From 052f20ed1da177c947ae224f41296923d903bf92 Mon Sep 17 00:00:00 2001 From: Pedro Date: Tue, 7 Mar 2017 15:30:54 +0100 Subject: [PATCH] add additonal TPC-H queries for testing --- test/queries/tpc-h-11-15.sql | 59 ++++++++++++++++++++++++++++++ test/queries/tpc-h-16-22.sql | 71 ++++++++++++++++++++++++++++++++++++ test/tpc_h_tests.cpp | 6 ++- 3 files changed, 134 insertions(+), 2 deletions(-) create mode 100644 test/queries/tpc-h-11-15.sql create mode 100644 test/queries/tpc-h-16-22.sql diff --git a/test/queries/tpc-h-11-15.sql b/test/queries/tpc-h-11-15.sql new file mode 100644 index 0000000..9f5318d --- /dev/null +++ b/test/queries/tpc-h-11-15.sql @@ -0,0 +1,59 @@ +-- From: +-- http://www.sqlserver-dba.com/2011/09/this-is-a-followup-on-my-earlier-post-of-sql-server-test-data-generation-testing-tools-i-had-some-requests-for-my-set-up-pr.html + +-- TPC_H Query 11 - Important Stock Identification +SELECT PS_PARTKEY, SUM(PS_SUPPLYCOST*PS_AVAILQTY) AS VALUE +FROM PARTSUPP, SUPPLIER, NATION +WHERE PS_SUPPKEY = S_SUPPKEY AND S_NATIONKEY = N_NATIONKEY AND N_NAME = 'GERMANY' +GROUP BY PS_PARTKEY +HAVING SUM(PS_SUPPLYCOST*PS_AVAILQTY) > (SELECT SUM(PS_SUPPLYCOST*PS_AVAILQTY) * 0.0001000000 + FROM PARTSUPP, SUPPLIER, NATION + WHERE PS_SUPPKEY = S_SUPPKEY AND S_NATIONKEY = N_NATIONKEY AND N_NAME = 'GERMANY') +ORDER BY VALUE DESC; + + +-- TPC_H Query 12 - Shipping Modes and Order Priority +SELECT L_SHIPMODE, +SUM(CASE WHEN O_ORDERPRIORITY = '1-URGENT' OR O_ORDERPRIORITY = '2-HIGH' THEN 1 ELSE 0 END) AS HIGH_LINE_COUNT, +SUM(CASE WHEN O_ORDERPRIORITY <> '1-URGENT' AND O_ORDERPRIORITY <> '2-HIGH' THEN 1 ELSE 0 END ) AS LOW_LINE_COUNT +FROM ORDERS, LINEITEM +WHERE O_ORDERKEY = L_ORDERKEY AND L_SHIPMODE IN ('MAIL','SHIP') +AND L_COMMITDATE < L_RECEIPTDATE AND L_SHIPDATE < L_COMMITDATE AND L_RECEIPTDATE >= '1994-01-01' +AND L_RECEIPTDATE < dateadd(mm, 1, cast('1995-09-01' as datetime)) +GROUP BY L_SHIPMODE +ORDER BY L_SHIPMODE; + + +-- TPC_H Query 13 - Customer Distribution +SELECT C_COUNT, COUNT(*) AS CUSTDIST +FROM (SELECT C_CUSTKEY, COUNT(O_ORDERKEY) + FROM CUSTOMER left outer join ORDERS on C_CUSTKEY = O_CUSTKEY + AND O_COMMENT not like '%%special%%requests%%' + GROUP BY C_CUSTKEY) AS C_ORDERS +GROUP BY C_COUNT +ORDER BY CUSTDIST DESC, C_COUNT DESC; + + +-- TPC_H Query 14 - Promotion Effect +SELECT 100.00* SUM(CASE WHEN P_TYPE LIKE 'PROMO%%' THEN L_EXTENDEDPRICE*(1-L_DISCOUNT) +ELSE 0 END) / SUM(L_EXTENDEDPRICE*(1-L_DISCOUNT)) AS PROMO_REVENUE +FROM LINEITEM, "PART" +WHERE L_PARTKEY = P_PARTKEY AND L_SHIPDATE >= '1995-09-01' AND L_SHIPDATE < dateadd(mm, 1, '1995-09-01'); + + +-- TPC_H Query 15.1 - Create View for Top Supplier Query +-- CREATE VIEW REVENUE0 (SUPPLIER_NO, TOTAL_REVENUE) AS +-- SELECT L_SUPPKEY, SUM(L_EXTENDEDPRICE*(1-L_DISCOUNT)) FROM LINEITEM +-- WHERE L_SHIPDATE >= '1996-01-01' AND L_SHIPDATE < dateadd(mm, 3, cast('1996-01-01' as datetime)) +-- GROUP BY L_SUPPKEY; + + +-- TPC_H Query 15.2 - Top Supplier +SELECT S_SUPPKEY, S_NAME, S_ADDRESS, S_PHONE, TOTAL_REVENUE +FROM SUPPLIER, REVENUE0 +WHERE S_SUPPKEY = SUPPLIER_NO AND TOTAL_REVENUE = (SELECT MAX(TOTAL_REVENUE) FROM REVENUE0) +ORDER BY S_SUPPKEY; + +-- TPC_H Query 15.3 - Drop View +-- DROP VIEW REVENUE0; + diff --git a/test/queries/tpc-h-16-22.sql b/test/queries/tpc-h-16-22.sql new file mode 100644 index 0000000..dd5f4cd --- /dev/null +++ b/test/queries/tpc-h-16-22.sql @@ -0,0 +1,71 @@ +-- From: +-- http://www.sqlserver-dba.com/2011/09/this-is-a-followup-on-my-earlier-post-of-sql-server-test-data-generation-testing-tools-i-had-some-requests-for-my-set-up-pr.html + +-- TPC_H Query 16 - Parts/Supplier Relationship +SELECT P_BRAND, P_TYPE, P_SIZE, COUNT(DISTINCT PS_SUPPKEY) AS SUPPLIER_CNT +FROM PARTSUPP, "PART" +WHERE P_PARTKEY = PS_PARTKEY AND P_BRAND <> 'Brand#45' AND P_TYPE NOT LIKE 'MEDIUM POLISHED%%' +AND P_SIZE IN (49, 14, 23, 45, 19, 3, 36, 9) AND PS_SUPPKEY NOT IN (SELECT S_SUPPKEY FROM SUPPLIER + WHERE S_COMMENT LIKE '%%Customer%%Complaints%%') +GROUP BY P_BRAND, P_TYPE, P_SIZE +ORDER BY SUPPLIER_CNT DESC, P_BRAND, P_TYPE, P_SIZE; + + +-- TPC_H Query 17 - Small-Quantity-Order Revenue +SELECT SUM(L_EXTENDEDPRICE)/7.0 AS AVG_YEARLY FROM LINEITEM, "PART" +WHERE P_PARTKEY = L_PARTKEY AND P_BRAND = 'Brand#23' AND P_CONTAINER = 'MED BOX' +AND L_QUANTITY < (SELECT 0.2*AVG(L_QUANTITY) FROM LINEITEM WHERE L_PARTKEY = P_PARTKEY); + + +-- TPC_H Query 18 - Large Volume Customer +SELECT TOP 100 C_NAME, C_CUSTKEY, O_ORDERKEY, O_ORDERDATE, O_TOTALPRICE, SUM(L_QUANTITY) +FROM CUSTOMER, ORDERS, LINEITEM +WHERE O_ORDERKEY IN (SELECT L_ORDERKEY FROM LINEITEM GROUP BY L_ORDERKEY HAVING + SUM(L_QUANTITY) > 300) AND C_CUSTKEY = O_CUSTKEY AND O_ORDERKEY = L_ORDERKEY +GROUP BY C_NAME, C_CUSTKEY, O_ORDERKEY, O_ORDERDATE, O_TOTALPRICE +ORDER BY O_TOTALPRICE DESC, O_ORDERDATE; + + +-- TPC_H Query 19 - Discounted Revenue +SELECT SUM(L_EXTENDEDPRICE* (1 - L_DISCOUNT)) AS REVENUE +FROM LINEITEM, "PART" +WHERE (P_PARTKEY = L_PARTKEY AND P_BRAND = 'Brand#12' AND P_CONTAINER IN ('SM CASE', 'SM BOX', 'SM PACK', 'SM PKG') AND L_QUANTITY >= 1 AND L_QUANTITY <= 1 + 10 AND P_SIZE BETWEEN 1 AND 5 +AND L_SHIPMODE IN ('AIR', 'AIR REG') AND L_SHIPINSTRUCT = 'DELIVER IN PERSON') +OR (P_PARTKEY = L_PARTKEY AND P_BRAND ='Brand#23' AND P_CONTAINER IN ('MED BAG', 'MED BOX', 'MED PKG', 'MED PACK') AND L_QUANTITY >=10 AND L_QUANTITY <=10 + 10 AND P_SIZE BETWEEN 1 AND 10 +AND L_SHIPMODE IN ('AIR', 'AIR REG') AND L_SHIPINSTRUCT = 'DELIVER IN PERSON') +OR (P_PARTKEY = L_PARTKEY AND P_BRAND = 'Brand#34' AND P_CONTAINER IN ( 'LG CASE', 'LG BOX', 'LG PACK', 'LG PKG') AND L_QUANTITY >=20 AND L_QUANTITY <= 20 + 10 AND P_SIZE BETWEEN 1 AND 15 +AND L_SHIPMODE IN ('AIR', 'AIR REG') AND L_SHIPINSTRUCT = 'DELIVER IN PERSON'); + + +-- TPC_H Query 20 - Potential Part Promotion +SELECT S_NAME, S_ADDRESS FROM SUPPLIER, NATION +WHERE S_SUPPKEY IN (SELECT PS_SUPPKEY FROM PARTSUPP + WHERE PS_PARTKEY in (SELECT P_PARTKEY FROM "PART" WHERE P_NAME like 'forest%%') AND + PS_AVAILQTY > (SELECT 0.5*sum(L_QUANTITY) FROM LINEITEM WHERE L_PARTKEY = PS_PARTKEY AND + L_SUPPKEY = PS_SUPPKEY AND L_SHIPDATE >= '1994-01-01' AND + L_SHIPDATE < dateadd(yy,1,'1994-01-01'))) AND S_NATIONKEY = N_NATIONKEY AND N_NAME = 'CANADA' +ORDER BY S_NAME; + + +-- TPC_H Query 21 - Suppliers Who Kept Orders Waiting +SELECT TOP 100 S_NAME, COUNT(*) AS NUMWAIT +FROM SUPPLIER, LINEITEM L1, ORDERS, NATION WHERE S_SUPPKEY = L1.L_SUPPKEY AND +O_ORDERKEY = L1.L_ORDERKEY AND O_ORDERSTATUS = 'F' AND L1.L_RECEIPTDATE> L1.L_COMMITDATE +AND EXISTS (SELECT * FROM LINEITEM L2 WHERE L2.L_ORDERKEY = L1.L_ORDERKEY + AND L2.L_SUPPKEY <> L1.L_SUPPKEY) AND +NOT EXISTS (SELECT * FROM LINEITEM L3 WHERE L3.L_ORDERKEY = L1.L_ORDERKEY AND + L3.L_SUPPKEY <> L1.L_SUPPKEY AND L3.L_RECEIPTDATE > L3.L_COMMITDATE) AND +S_NATIONKEY = N_NATIONKEY AND N_NAME = 'SAUDI ARABIA' +GROUP BY S_NAME +ORDER BY NUMWAIT DESC, S_NAME; + + +-- TPC_H Query 22 - Global Sales Opportunity */ +SELECT CNTRYCODE, COUNT(*) AS NUMCUST, SUM(C_ACCTBAL) AS TOTACCTBAL +FROM (SELECT SUBSTRING(C_PHONE,1,2) AS CNTRYCODE, C_ACCTBAL + FROM CUSTOMER WHERE SUBSTRING(C_PHONE,1,2) IN ('13', '31', '23', '29', '30', '18', '17') AND + C_ACCTBAL > (SELECT AVG(C_ACCTBAL) FROM CUSTOMER WHERE C_ACCTBAL > 0.00 AND + SUBSTRING(C_PHONE,1,2) IN ('13', '31', '23', '29', '30', '18', '17')) AND + NOT EXISTS ( SELECT * FROM ORDERS WHERE O_CUSTKEY = C_CUSTKEY)) AS CUSTSALE +GROUP BY CNTRYCODE +ORDER BY CNTRYCODE; \ No newline at end of file diff --git a/test/tpc_h_tests.cpp b/test/tpc_h_tests.cpp index bb65a65..614d18f 100644 --- a/test/tpc_h_tests.cpp +++ b/test/tpc_h_tests.cpp @@ -10,7 +10,7 @@ using namespace hsql; -TEST(TPCHQueryTests) { +TEST(TPCHQueryGrammarTests) { std::vector files = { "test/queries/tpc-h-01.sql", "test/queries/tpc-h-02.sql", @@ -21,7 +21,9 @@ TEST(TPCHQueryTests) { "test/queries/tpc-h-07.sql", "test/queries/tpc-h-08.sql", "test/queries/tpc-h-09.sql", - "test/queries/tpc-h-10.sql" + "test/queries/tpc-h-10.sql", + "test/queries/tpc-h-11-15.sql", + "test/queries/tpc-h-16-22.sql" }; int testsFailed = 0;