ClickBench is a benchmarking tool developed by ClickHouse, Inc to evaluate database performance in large-scale analytical scenarios. ClickBench includes a dataset with 43 SQL queries specifically created for performance testing. This topic describes how to use ClickBench to test the performance of read-only columnar instances.
Test design
Test data
Test table: 105 columns, including 19 INTEGER columns, 6 BIGINT columns, 48 SMALLINT columns, 26 TEXT columns, 1 VARCHAR column, 1 TIMESTAMP column, and 1 DATE column.
Data amount: approximately 100 million rows.
Dataset size: 70 GB.
Data examples:
9110818468285196899 0 1 2013-07-14 20:38:47 2013-07-15 17 -1216690514 839 -2461439046089301801 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 �O 0 0 0 0 3793327 4 0 0 0 0 0 -1 1971-01-01 14:16:06 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 5 2013-07-15 10:47:34 0 0 0 0 0 -1001831330 -1 -1 -1 � �\f 0 0 0 0 0 0 0 0 0 NH 0 0 -296158784638538920 -8417682003818480435 0
8156744413230856864 0 1 2013-07-15 18:33:50 2013-07-15 17 -1216690514 839 -2461439046089301801 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 �O 0 0 0 0 3793327 4 0 0 0 0 0 -1 1971-01-01 14:16:06 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 5 2013-07-15 08:37:59 0 0 0 0 0 -1001831330 -1 -1 -1 � �\f 0 0 0 0 0 0 0 0 0 NH 0 0 -296158784638538920 -8417682003818480435 0
5581899925183342605 1 @дневники, работа и женщин поступивая ул, попохорошем качество дал 1 2013-07-15 15:45:23 2013-07-15 38 2050260421 2 -9214751021948998350 0 44 5 https://produkty%2Fkategory_id=0&last_auto_id=&autodoc.ru/proskategory/sell/reside.travel.ru/recipe/viewtopic,375;sa=shop.ru/san https://go.mail/folder-1/online/ru-en/#lingvo/#1О 50000&price_ashka/rav4/page=/check.xml 0 14550 952 15014 519 1917 879 37 15 13 800 0 0 31 D� 1 1 0 0 209623 3 2 авомосква веб каменисный 0 0 745 438 135 2013-07-15 10:14:30 4 1 31337 0 windows-1251;charset 1601 0 0 0 8570394295480778849 178995092 0 0 0 0 0 5 2013-07-15 15:10:45 31 1 2 70 17 1437531235 -1 -1 -1 S0 �\f 0 0 0 3 1300 460 284 0 0 NH 0 0 -823144271007412007 -5847714421347370287 0
8407760668305829074 1 @дневники, работа и женщин поступивая ул, попохорошем качество дал 1 2013-07-15 15:45:24 2013-07-15 38 2050260421 2 -9214751021948998350 0 44 5 https://produkty%2Fkategory_id=0&last_auto_id=&autodoc.ru/proskategory/sell/reside.travel.ru/recipe/viewtopic,375;sa=shop.ru/san https://go.mail/folder-1/online/ru-en/#lingvo/#1О 50000&price_ashka/rav4/page=/check.xml 1 14550 952 15014 519 1917 879 37 15 13 800 0 0 31 D� 1 1 0 0 209623 3 2 авомосква веб каменисный 0 1 745 438 135 2013-07-15 10:14:30 4 1 31337 0 windows-1251;charset 1601 0 0 0 8570394295480778849 178995092 0 0 0 0 0 5 2013-07-15 15:10:46 31 1 2 70 17 1437531235 -1 -1 -1 S0 �\f 0 0 0 0 0 0 0 0 0 NH 0 0 -823144271007412007 -5847714421347370287 0Test SQL examples:
SELECT COUNT(*) FROM hits WHERE AdvEngineID <> 0;
SELECT AdvEngineID, COUNT(*) FROM hits WHERE AdvEngineID <> 0 GROUP BY AdvEngineID ORDER BY COUNT(*) DESC;
SELECT RegionID, COUNT(DISTINCT UserID) AS u FROM hits GROUP BY RegionID ORDER BY u DESC LIMIT 10;Instance specifications
The test focuses on testing the performance of databases in the columnar store mode. The following table lists only the specifications of read-only columnar instances.
The test results are not affected by the version and specifications of the primary instance.
To prevent memory overflow and test failure, make sure that the memory of a single read-only columnar instance is at least 32 GB.
For more information, see Create a PolarDB-X instance, Change instance specifications, Add a read-only column store instance, and Add or remove nodes.
Specification of the read-only columnar instance | Number of compute nodes in the read-only columnar instance |
4 cores, 32 GB memory | 2 |
8 cores, 32 GB memory | 2 |
8 cores, 32 GB memory | 4 |
16 cores, 64 GB memory | 2 |
16 cores, 64 GB memory | 4 |
Specifications of the ECS instance
ecs.g8i.16xlarge (64 vCPUs, 256 GB memory, 200 GB disk space), JDK 11 installed
Test method
Preparations
Execute the following commands on the ECS instance to download and decompress the dataset package:
wget https://datasets.clickhouse.com/hits_compatible/hits.tsv.gz gunzip hits.tsv.gzExecute the following SQL statements on the primary PolarDB-X instance to create a test database and table:
CREATE DATABASE clickbench MODE = 'auto'; CREATE TABLE hits ( WatchID BIGINT NOT NULL, JavaEnable SMALLINT NOT NULL, Title TEXT NOT NULL, GoodEvent SMALLINT NOT NULL, EventTime TIMESTAMP NOT NULL, EventDate Date NOT NULL, CounterID INTEGER NOT NULL, ClientIP INTEGER NOT NULL, RegionID INTEGER NOT NULL, UserID BIGINT NOT NULL, CounterClass SMALLINT NOT NULL, OS SMALLINT NOT NULL, UserAgent SMALLINT NOT NULL, URL TEXT NOT NULL, Referer TEXT NOT NULL, IsRefresh SMALLINT NOT NULL, RefererCategoryID SMALLINT NOT NULL, RefererRegionID INTEGER NOT NULL, URLCategoryID SMALLINT NOT NULL, URLRegionID INTEGER NOT NULL, ResolutionWidth SMALLINT NOT NULL, ResolutionHeight SMALLINT NOT NULL, ResolutionDepth SMALLINT NOT NULL, FlashMajor SMALLINT NOT NULL, FlashMinor SMALLINT NOT NULL, FlashMinor2 TEXT NOT NULL, NetMajor SMALLINT NOT NULL, NetMinor SMALLINT NOT NULL, UserAgentMajor SMALLINT NOT NULL, UserAgentMinor VARCHAR(255) NOT NULL, CookieEnable SMALLINT NOT NULL, JavascriptEnable SMALLINT NOT NULL, IsMobile SMALLINT NOT NULL, MobilePhone SMALLINT NOT NULL, MobilePhoneModel TEXT NOT NULL, Params TEXT NOT NULL, IPNetworkID INTEGER NOT NULL, TraficSourceID SMALLINT NOT NULL, SearchEngineID SMALLINT NOT NULL, SearchPhrase TEXT NOT NULL, AdvEngineID SMALLINT NOT NULL, IsArtifical SMALLINT NOT NULL, WindowClientWidth SMALLINT NOT NULL, WindowClientHeight SMALLINT NOT NULL, ClientTimeZone SMALLINT NOT NULL, ClientEventTime TIMESTAMP NOT NULL, SilverlightVersion1 SMALLINT NOT NULL, SilverlightVersion2 SMALLINT NOT NULL, SilverlightVersion3 INTEGER NOT NULL, SilverlightVersion4 SMALLINT NOT NULL, PageCharset TEXT NOT NULL, CodeVersion INTEGER NOT NULL, IsLink SMALLINT NOT NULL, IsDownload SMALLINT NOT NULL, IsNotBounce SMALLINT NOT NULL, FUniqID BIGINT NOT NULL, OriginalURL TEXT NOT NULL, HID INTEGER NOT NULL, IsOldCounter SMALLINT NOT NULL, IsEvent SMALLINT NOT NULL, IsParameter SMALLINT NOT NULL, DontCountHits SMALLINT NOT NULL, WithHash SMALLINT NOT NULL, HitColor CHAR NOT NULL, LocalEventTime TIMESTAMP NOT NULL, Age SMALLINT NOT NULL, Sex SMALLINT NOT NULL, Income SMALLINT NOT NULL, Interests SMALLINT NOT NULL, Robotness SMALLINT NOT NULL, RemoteIP INTEGER NOT NULL, WindowName INTEGER NOT NULL, OpenerName INTEGER NOT NULL, HistoryLength SMALLINT NOT NULL, BrowserLanguage TEXT NOT NULL, BrowserCountry TEXT NOT NULL, SocialNetwork TEXT NOT NULL, SocialAction TEXT NOT NULL, HTTPError SMALLINT NOT NULL, SendTiming INTEGER NOT NULL, DNSTiming INTEGER NOT NULL, ConnectTiming INTEGER NOT NULL, ResponseStartTiming INTEGER NOT NULL, ResponseEndTiming INTEGER NOT NULL, FetchTiming INTEGER NOT NULL, SocialSourceNetworkID SMALLINT NOT NULL, SocialSourcePage TEXT NOT NULL, ParamPrice BIGINT NOT NULL, ParamOrderID TEXT NOT NULL, ParamCurrency TEXT NOT NULL, ParamCurrencyID SMALLINT NOT NULL, OpenstatServiceName TEXT NOT NULL, OpenstatCampaignID TEXT NOT NULL, OpenstatAdID TEXT NOT NULL, OpenstatSourceID TEXT NOT NULL, UTMSource TEXT NOT NULL, UTMMedium TEXT NOT NULL, UTMCampaign TEXT NOT NULL, UTMContent TEXT NOT NULL, UTMTerm TEXT NOT NULL, FromTag TEXT NOT NULL, HasGCLID SMALLINT NOT NULL, RefererHash BIGINT NOT NULL, URLHash BIGINT NOT NULL, CLID INTEGER NOT NULL, PRIMARY KEY (CounterID, EventDate, UserID, EventTime, WatchID) ) partition by key(UserID) partitions 24;Import data.
Save the following command to a file named
load.shon the ECS instance and run the script by executing thesh load.shcommand to import data:java -Xmn4g -Xmx6g -jar batch-tool.jar -h127.0.0.1 -P3306 -uroot -pPassword -D clickbench -o import -t hits -s " " -pro 1 -con 16 -minConn 8 -maxConn 16 -batchSize 100 -f hits.tsv -quote AUTO 2>&1 >> hits.logNoteFor the installation and usage instructions for
batch-tool.jar, see Use Batch Tool to export and import data.Parameters:
Parameter
Description
-h
The database connection address.
-P
The port number for the database connection.
-u
The username for the database connection.
-p
The password for the database connection.
-D
The database name, which is
clickbenchin this example.-t
The table name, which is
hitsin this example.-s
The data separator in the
hits.tsvfile after the dataset is decompressed, which is a tab character in this example.-f
The name of the data file, which is
hits.tsvin this example.-Xmn
The size of the JVM young generation, which can be adjusted based on the ECS configuration.
-Xmx
The maximum heap size for the JVM, which can be adjusted based on the ECS configuration.
NoteThe preceding parameters can be adjusted based on your business requirements.
After data is imported, execute the following SQL statement in the
clickbenchdatabase to create a clustered columnar index (CCI) for thehitstable:CREATE CLUSTERED COLUMNAR INDEX cci_hits ON hits(EventDate) PARTITION BY HASH(`UserID`) PARTITIONS 64;NoteFor more information, see CCI.
Database parameter tuning
SET GLOBAL RECORD_SQL = false;
SET GLOBAL MPP_METRIC_LEVEL = 0;
SET GLOBAL ENABLE_CPU_PROFILE = false;
SET GLOBAL ENABLE_BACKGROUND_STATISTIC_COLLECTION=false;
SET GLOBAL ENABLE_STATISTIC_FEEDBACK=false;
SET GLOBAL ENABLE_MPP_SERIALIZED_CHUNK_COMPRESSION = true;
SET GLOBAL ENABLE_OSS_COMPATIBLE = false;
SET GLOBAL MPP_TASK_LOCAL_MAX_BUFFER_SIZE = 32000000000;
SET GLOBAL MPP_OUTPUT_MAX_BUFFER_SIZE = 32000000000;
SET GLOBAL MPP_EXCHANGE_MAX_RESPONSE_SIZE = 32000000000;
SET GLOBAL ENABLE_STREAM_PARTIAL_AGG = true;
SET GLOBAL ENABLE_TRANSPARENT_PARTIAL_AGG = true;
SET GLOBAL ENABLE_SIMPLIFY_GROUP_BY_RULE = true;Disable logging, CPU profiling, and automatic collection of statistics for the database.
Execute the test script
Save the following code to a file named
click.shon the ECS instance and specify the-h,-P,-u, and-Dparameters inclick.shbased on your business requirements:sql_queries=("SELECT COUNT(*) FROM hits;" "SELECT COUNT(*) FROM hits WHERE AdvEngineID <> 0;" "SELECT SUM(AdvEngineID), COUNT(*), AVG(ResolutionWidth) FROM hits;" "SELECT AVG(UserID) FROM hits;" "SELECT COUNT(DISTINCT UserID) FROM hits;" "SELECT COUNT(DISTINCT SearchPhrase) FROM hits;" "SELECT MIN(EventDate), MAX(EventDate) FROM hits;" "SELECT AdvEngineID, COUNT(*) FROM hits WHERE AdvEngineID <> 0 GROUP BY AdvEngineID ORDER BY COUNT(*) DESC;" "SELECT RegionID, COUNT(DISTINCT UserID) AS u FROM hits GROUP BY RegionID ORDER BY u DESC LIMIT 10;" "SELECT RegionID, SUM(AdvEngineID), COUNT(*) AS c, AVG(ResolutionWidth), COUNT(DISTINCT UserID) FROM hits GROUP BY RegionID ORDER BY c DESC LIMIT 10;" "SELECT MobilePhoneModel, COUNT(DISTINCT UserID) AS u FROM hits WHERE MobilePhoneModel <> '' GROUP BY MobilePhoneModel ORDER BY u DESC LIMIT 10;" "SELECT MobilePhone, MobilePhoneModel, COUNT(DISTINCT UserID) AS u FROM hits WHERE MobilePhoneModel <> '' GROUP BY MobilePhone, MobilePhoneModel ORDER BY u DESC LIMIT 10;" "SELECT SearchPhrase, COUNT(*) AS c FROM hits WHERE SearchPhrase <> '' GROUP BY SearchPhrase ORDER BY c DESC LIMIT 10;" "SELECT SearchPhrase, COUNT(DISTINCT UserID) AS u FROM hits WHERE SearchPhrase <> '' GROUP BY SearchPhrase ORDER BY u DESC LIMIT 10;" "SELECT SearchEngineID, SearchPhrase, COUNT(*) AS c FROM hits WHERE SearchPhrase <> '' GROUP BY SearchEngineID, SearchPhrase ORDER BY c DESC LIMIT 10;" "SELECT UserID, COUNT(*) FROM hits GROUP BY UserID ORDER BY COUNT(*) DESC LIMIT 10;" "SELECT UserID, SearchPhrase, COUNT(*) FROM hits GROUP BY UserID, SearchPhrase ORDER BY COUNT(*) DESC LIMIT 10;" "SELECT UserID, SearchPhrase, COUNT(*) FROM hits GROUP BY UserID, SearchPhrase LIMIT 10;" "SELECT UserID, extract(minute FROM EventTime) AS m, SearchPhrase, COUNT(*) FROM hits GROUP BY UserID, m, SearchPhrase ORDER BY COUNT(*) DESC LIMIT 10;" "SELECT UserID FROM hits WHERE UserID = 435090932899640449;" "SELECT COUNT(*) FROM hits WHERE URL LIKE '%google%';" "SELECT SearchPhrase, MIN(URL), COUNT(*) AS c FROM hits WHERE URL LIKE '%google%' AND SearchPhrase <> '' GROUP BY SearchPhrase ORDER BY c DESC LIMIT 10;" "SELECT SearchPhrase, MIN(URL), MIN(Title), COUNT(*) AS c, COUNT(DISTINCT UserID) FROM hits WHERE Title LIKE '%Google%' AND URL NOT LIKE '%.google.%' AND SearchPhrase <> '' GROUP BY SearchPhrase ORDER BY c DESC LIMIT 10;" "SELECT * FROM hits WHERE URL LIKE '%google%' ORDER BY EventTime LIMIT 10;" "SELECT SearchPhrase FROM hits WHERE SearchPhrase <> '' ORDER BY EventTime LIMIT 10;" "SELECT SearchPhrase FROM hits WHERE SearchPhrase <> '' ORDER BY SearchPhrase LIMIT 10;" "SELECT SearchPhrase FROM hits WHERE SearchPhrase <> '' ORDER BY EventTime, SearchPhrase LIMIT 10;" "SELECT CounterID, AVG(length(URL)) AS l, COUNT(*) AS c FROM hits WHERE URL <> '' GROUP BY CounterID HAVING COUNT(*) > 100000 ORDER BY l DESC LIMIT 25;" "SELECT REGEXP_REPLACE(Referer, '^https?://(?:www\\.)?([^/]+)/.*$', '\1') AS k, AVG(length(Referer)) AS l, COUNT(*) AS c, MIN(Referer) FROM hits WHERE Referer <> '' GROUP BY k HAVING COUNT(*) > 100000 ORDER BY l DESC LIMIT 25;" "SELECT SUM(ResolutionWidth), SUM(ResolutionWidth + 1), SUM(ResolutionWidth + 2), SUM(ResolutionWidth + 3), SUM(ResolutionWidth + 4), SUM(ResolutionWidth + 5), SUM(ResolutionWidth + 6), SUM(ResolutionWidth + 7), SUM(ResolutionWidth + 8), SUM(ResolutionWidth + 9), SUM(ResolutionWidth + 10), SUM(ResolutionWidth + 11), SUM(ResolutionWidth + 12), SUM(ResolutionWidth + 13), SUM(ResolutionWidth + 14), SUM(ResolutionWidth + 15), SUM(ResolutionWidth + 16), SUM(ResolutionWidth + 17), SUM(ResolutionWidth + 18), SUM(ResolutionWidth + 19), SUM(ResolutionWidth + 20), SUM(ResolutionWidth + 21), SUM(ResolutionWidth + 22), SUM(ResolutionWidth + 23), SUM(ResolutionWidth + 24), SUM(ResolutionWidth + 25), SUM(ResolutionWidth + 26), SUM(ResolutionWidth + 27), SUM(ResolutionWidth + 28), SUM(ResolutionWidth + 29), SUM(ResolutionWidth + 30), SUM(ResolutionWidth + 31), SUM(ResolutionWidth + 32), SUM(ResolutionWidth + 33), SUM(ResolutionWidth + 34), SUM(ResolutionWidth + 35), SUM(ResolutionWidth + 36), SUM(ResolutionWidth + 37), SUM(ResolutionWidth + 38), SUM(ResolutionWidth + 39), SUM(ResolutionWidth + 40), SUM(ResolutionWidth + 41), SUM(ResolutionWidth + 42), SUM(ResolutionWidth + 43), SUM(ResolutionWidth + 44), SUM(ResolutionWidth + 45), SUM(ResolutionWidth + 46), SUM(ResolutionWidth + 47), SUM(ResolutionWidth + 48), SUM(ResolutionWidth + 49), SUM(ResolutionWidth + 50), SUM(ResolutionWidth + 51), SUM(ResolutionWidth + 52), SUM(ResolutionWidth + 53), SUM(ResolutionWidth + 54), SUM(ResolutionWidth + 55), SUM(ResolutionWidth + 56), SUM(ResolutionWidth + 57), SUM(ResolutionWidth + 58), SUM(ResolutionWidth + 59), SUM(ResolutionWidth + 60), SUM(ResolutionWidth + 61), SUM(ResolutionWidth + 62), SUM(ResolutionWidth + 63), SUM(ResolutionWidth + 64), SUM(ResolutionWidth + 65), SUM(ResolutionWidth + 66), SUM(ResolutionWidth + 67), SUM(ResolutionWidth + 68), SUM(ResolutionWidth + 69), SUM(ResolutionWidth + 70), SUM(ResolutionWidth + 71), SUM(ResolutionWidth + 72), SUM(ResolutionWidth + 73), SUM(ResolutionWidth + 74), SUM(ResolutionWidth + 75), SUM(ResolutionWidth + 76), SUM(ResolutionWidth + 77), SUM(ResolutionWidth + 78), SUM(ResolutionWidth + 79), SUM(ResolutionWidth + 80), SUM(ResolutionWidth + 81),SUM(ResolutionWidth + 82), SUM(ResolutionWidth + 83), SUM(ResolutionWidth + 84), SUM(ResolutionWidth + 85), SUM(ResolutionWidth + 86), SUM(ResolutionWidth + 87), SUM(ResolutionWidth + 88), SUM(ResolutionWidth + 89) FROM hits;" "SELECT SearchEngineID, ClientIP, COUNT(*) AS c, SUM(IsRefresh), AVG(ResolutionWidth) FROM hits WHERE SearchPhrase <> '' GROUP BY SearchEngineID, ClientIP ORDER BY c DESC LIMIT 10;" "SELECT WatchID, ClientIP, COUNT(*) AS c, SUM(IsRefresh), AVG(ResolutionWidth) FROM hits WHERE SearchPhrase <> '' GROUP BY WatchID, ClientIP ORDER BY c DESC LIMIT 10;" "SELECT WatchID, ClientIP, COUNT(*) AS c, SUM(IsRefresh), AVG(ResolutionWidth) FROM hits GROUP BY WatchID, ClientIP ORDER BY c DESC LIMIT 10;" "SELECT URL, COUNT(*) AS c FROM hits GROUP BY URL ORDER BY c DESC LIMIT 10;" "SELECT 1, URL, COUNT(*) AS c FROM hits GROUP BY 1, URL ORDER BY c DESC LIMIT 10;" "SELECT ClientIP, ClientIP - 1, ClientIP - 2, ClientIP - 3, COUNT(*) AS c FROM hits GROUP BY ClientIP, ClientIP - 1, ClientIP - 2, ClientIP - 3 ORDER BY c DESC LIMIT 10;" "SELECT URL, COUNT(*) AS PageViews FROM hits WHERE CounterID = 62 AND EventDate >= '2013-07-01' AND EventDate <= '2013-07-31' AND DontCountHits = 0 AND IsRefresh = 0 AND URL <> '' GROUP BY URL ORDER BY PageViews DESC LIMIT 10;" "SELECT Title, COUNT(*) AS PageViews FROM hits WHERE CounterID = 62 AND EventDate >= '2013-07-01' AND EventDate <= '2013-07-31' AND DontCountHits = 0 AND IsRefresh = 0 AND Title <> '' GROUP BY Title ORDER BY PageViews DESC LIMIT 10;" "SELECT URL, COUNT(*) AS PageViews FROM hits WHERE CounterID = 62 AND EventDate >= '2013-07-01' AND EventDate <= '2013-07-31' AND IsRefresh = 0 AND IsLink <> 0 AND IsDownload = 0 GROUP BY URL ORDER BY PageViews DESC LIMIT 10 OFFSET 1000;" "SELECT TraficSourceID, SearchEngineID, AdvEngineID, CASE WHEN (SearchEngineID = 0 AND AdvEngineID = 0) THEN Referer ELSE '' END AS Src, URL AS Dst, COUNT(*) AS PageViews FROM hits WHERE CounterID = 62 AND EventDate >= '2013-07-01' AND EventDate <= '2013-07-31' AND IsRefresh = 0 GROUP BY TraficSourceID, SearchEngineID, AdvEngineID, Src, Dst ORDER BY PageViews DESC LIMIT 10 OFFSET 1000;" "SELECT URLHash, EventDate, COUNT(*) AS PageViews FROM hits WHERE CounterID = 62 AND EventDate >= '2013-07-01' AND EventDate <= '2013-07-31' AND IsRefresh = 0 AND TraficSourceID IN (-1, 6) AND RefererHash = 3594120000172545465 GROUP BY URLHash, EventDate ORDER BY PageViews DESC LIMIT 10 OFFSET 100;" "SELECT WindowClientWidth, WindowClientHeight, COUNT(*) AS PageViews FROM hits WHERE CounterID = 62 AND EventDate >= '2013-07-01' AND EventDate <= '2013-07-31' AND IsRefresh = 0 AND DontCountHits = 0 AND URLHash = 2868770270353813622 GROUP BY WindowClientWidth, WindowClientHeight ORDER BY PageViews DESC LIMIT 10 OFFSET 10000;" "SELECT DATE_FORMAT(EventTime, '%Y-%m-%d %H:00:00') AS M, COUNT(*) AS PageViews FROM hits WHERE CounterID = 62 AND EventDate >= '2013-07-14' AND EventDate <= '2013-07-15' AND IsRefresh = 0 AND DontCountHits = 0 GROUP BY DATE_FORMAT(EventTime, '%Y-%m-%d %H:00:00') ORDER BY DATE_FORMAT(EventTime, '%Y-%m-%d %H:00:00') LIMIT 10 OFFSET 1000;" ) # Initialize total_time variable total_time=0 # Loop through the array of SQL queries for i in "${!sql_queries[@]}"; do echo -n "Q$((i + 1)): " min_time=999999 # Set a high initial value # Execute the SQL three times for j in {1..3}; do TIMEFORMAT=%R; exec_time=$( (time mysql -h127.0.0.1 -P $serverPort -uusername -Dclickbench -Ac -e "${sql_queries[i]}" > /dev/null) 2>&1 ) # Check for errors in execution last_status=$? if [ $last_status -ne 0 ]; then echo "Error executing Q$((i + 1))" continue 2 # Skip to next query fi # Get the execution time (in seconds) exec_time=$(echo $exec_time | awk '{print $NF}') # Update min_time if current exec_time is smaller if (( $(echo "$exec_time < $min_time" | bc -l) )); then min_time=$exec_time fi done if [ $min_time == 999999 ]; then echo "No valid execution time" else echo $min_time # Add the min_time to total_time total_time=$(echo "$total_time + $min_time" | bc) fi done # Print the total execution time echo "Total execution time: $total_time"Execute the
sh click.shcommand to run theclick.shscript.
Test results
The results in the following table are in seconds.
Query | Specification of the read-only columnar instance | ||||
2 × 4 cores, 32 GB memory | 2 × 8 cores, 32 GB memory | 4 × 8 cores, 32 GB memory | 2 × 16 cores, 64 GB memory | 4 × 16 cores, 64 GB memory | |
SQL1 | 0.106 | 0.121 | 0.095 | 0.14 | 0.078 |
SQL2 | 0.076 | 0.073 | 0.058 | 0.085 | 0.052 |
SQL3 | 0.712 | 0.399 | 0.229 | 0.32 | 0.178 |
SQL4 | 0.554 | 0.257 | 0.181 | 0.212 | 0.141 |
SQL5 | 0.606 | 0.258 | 0.19 | 0.128 | 0.153 |
SQL6 | 1.589 | 0.515 | 0.343 | 0.559 | 0.276 |
SQL7 | 0.235 | 0.224 | 0.09 | 0.128 | 0.081 |
SQL8 | 0.067 | 0.072 | 0.06 | 0.087 | 0.055 |
SQL9 | 0.805 | 0.432 | 0.274 | 0.187 | 0.189 |
SQL10 | 7.438 | 0.825 | 0.484 | 0.603 | 0.268 |
SQL11 | 0.589 | 0.19 | 0.096 | 0.095 | 0.083 |
SQL12 | 0.553 | 0.316 | 0.22 | 0.45 | 0.165 |
SQL13 | 1.442 | 0.793 | 0.349 | 0.462 | 0.298 |
SQL14 | 1.965 | 0.906 | 0.401 | 0.59 | 0.345 |
SQL15 | 1.726 | 0.944 | 0.936 | 0.508 | 0.585 |
SQL16 | 0.536 | 0.402 | 0.211 | 0.137 | 0.192 |
SQL17 | 1.84 | 1.396 | 0.591 | 0.445 | 0.345 |
SQL18 | 1.84 | 1.188 | 0.533 | 0.322 | 0.305 |
SQL19 | 4.71 | 2.542 | 1.005 | 1.076 | 0.639 |
SQL20 | 0.017 | 0.018 | 0.018 | 0.012 | 0.018 |
SQL21 | 0.368 | 0.23 | 0.125 | 0.128 | 0.122 |
SQL22 | 0.457 | 0.308 | 0.169 | 0.161 | 0.14 |
SQL23 | 1.464 | 0.807 | 0.275 | 0.272 | 0.234 |
SQL24 | 1.127 | 0.991 | 0.393 | 1.67 | 0.32 |
SQL25 | 0.147 | 0.102 | 0.062 | 0.065 | 0.054 |
SQL26 | 0.261 | 0.148 | 0.081 | 0.112 | 0.078 |
SQL27 | 0.267 | 0.173 | 0.082 | 0.109 | 0.077 |
SQL28 | 1.502 | 1.11 | 0.516 | 0.672 | 0.401 |
SQL29 | 13.023 | 9.534 | 4.633 | 6.325 | 3.603 |
SQL30 | 0.404 | 0.252 | 0.181 | 0.212 | 0.136 |
SQL31 | 0.996 | 0.557 | 0.303 | 0.351 | 0.23 |
SQL32 | 1.527 | 0.941 | 0.38 | 0.458 | 0.303 |
SQL33 | 10.873 | 7.203 | 2.551 | 2.875 | 1.754 |
SQL34 | 17.157 | 5.941 | 3.428 | 3.256 | 2.326 |
SQL35 | 18.025 | 5.674 | 3.485 | 3.384 | 2.414 |
SQL36 | 0.72 | 0.432 | 0.223 | 0.321 | 0.228 |
SQL37 | 0.103 | 0.087 | 0.056 | 0.069 | 0.05 |
SQL38 | 0.054 | 0.048 | 0.038 | 0.052 | 0.039 |
SQL39 | 0.04 | 0.088 | 0.033 | 0.049 | 0.034 |
SQL40 | 0.24 | 0.181 | 0.094 | 0.11 | 0.091 |
SQL41 | 0.139 | 0.117 | 0.035 | 0.055 | 0.04 |
SQL42 | 0.137 | 0.132 | 0.068 | 0.208 | 0.067 |
SQL43 | 0.059 | 0.063 | 0.05 | 0.044 | 0.038 |
Total | 96.496 | 46.99 | 23.625 | 27.504 | 17.225 |