├── TPCH ├── hq6.sql ├── hq13.sql ├── hq14.sql ├── hq4.sql ├── hq17.sql ├── hq3.sql ├── hq5.sql ├── hq1.sql ├── hq15.sql ├── hq18.sql ├── hq11.sql ├── hq16.sql ├── hq10.sql ├── hq9.sql ├── hq22.sql ├── hq20.sql ├── hq12.sql ├── hq21.sql ├── hq7.sql ├── hq8.sql ├── hq2.sql ├── hq19.sql ├── create_tables.sql └── create_tables_lakehouse.sql ├── THIRD_PARTY_LICENSES.txt ├── HeatWave ├── secondary_load_lakehouse.sql └── secondary_load.sql ├── SECURITY.md ├── LICENSE.txt └── README.md /TPCH/hq6.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 6 - Forecasting Revenue Change 7 | SELECT 8 | SUM(l_extendedprice * l_discount) AS revenue 9 | FROM 10 | LINEITEM 11 | WHERE 12 | l_shipdate >= DATE '1994-01-01' 13 | AND l_shipdate < DATE '1994-01-01' + INTERVAL '1' YEAR 14 | AND l_discount BETWEEN 0.06 - 0.01 AND 0.06 + 0.01 15 | AND l_quantity < 24; -------------------------------------------------------------------------------- /THIRD_PARTY_LICENSES.txt: -------------------------------------------------------------------------------- 1 | The SQL queries and table creation DDL derive from material licensed as follows: 2 | TPC Benchmark™, TPC-H, QppH, QthH, and QphH are trademarks of the Transaction Processing Performance Council. 3 | All parties are granted permission to copy and distribute to any party without fee all or part of this material 4 | provided that: 1) copying and distribution is done for the primary purpose of disseminating TPC material; 5 | 2) the TPC copyright notice, the title of the publication, and its date appear, and notice is given that copying 6 | is by permission of the Transaction Processing Performance Council. 7 | -------------------------------------------------------------------------------- /TPCH/hq13.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 13 - Customer Distribution 7 | SELECT 8 | c_count, COUNT(*) AS custdist 9 | FROM 10 | (SELECT 11 | c_custkey, COUNT(o_orderkey) AS c_count 12 | FROM 13 | CUSTOMER 14 | LEFT OUTER JOIN ORDERS ON (c_custkey = o_custkey 15 | AND o_comment NOT LIKE '%special%requests%') 16 | GROUP BY c_custkey) AS c_orders 17 | GROUP BY c_count 18 | ORDER BY custdist DESC , c_count DESC; -------------------------------------------------------------------------------- /TPCH/hq14.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 14 - Promotion Effect 7 | SELECT 8 | 100.00 * SUM(CASE 9 | WHEN p_type LIKE 'PROMO%' THEN l_extendedprice * (1 - l_discount) 10 | ELSE 0 11 | END) / SUM(l_extendedprice * (1 - l_discount)) AS promo_revenue 12 | FROM 13 | LINEITEM, 14 | PART 15 | WHERE 16 | l_partkey = p_partkey 17 | AND l_shipdate >= DATE '1995-09-01' 18 | AND l_shipdate < DATE '1995-09-01' + INTERVAL '1' MONTH; -------------------------------------------------------------------------------- /TPCH/hq4.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 4 - Order Priority Checking 7 | SELECT 8 | O_ORDERPRIORITY, COUNT(*) AS ORDER_COUNT 9 | FROM 10 | ORDERS 11 | WHERE 12 | O_ORDERDATE >= DATE '1994-03-01' 13 | AND O_ORDERDATE < DATE '1994-03-01' + INTERVAL '3' MONTH 14 | AND EXISTS( SELECT 15 | * 16 | FROM 17 | LINEITEM 18 | WHERE 19 | L_ORDERKEY = O_ORDERKEY 20 | AND L_COMMITDATE < L_RECEIPTDATE) 21 | GROUP BY O_ORDERPRIORITY 22 | ORDER BY O_ORDERPRIORITY; -------------------------------------------------------------------------------- /HeatWave/secondary_load_lakehouse.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2022, Oralce and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl 3 | 4 | -- data placement 5 | alter table LINEITEM secondary_engine NULL; 6 | alter table LINEITEM change L_ORDERKEY L_ORDERKEY BIGINT NOT NULL COMMENT 'RAPID_COLUMN=DATA_PLACEMENT_KEY=1'; 7 | alter table LINEITEM secondary_engine RAPID; 8 | 9 | alter table LINEITEM secondary_load; 10 | alter table ORDERS secondary_load; 11 | alter table CUSTOMER secondary_load; 12 | alter table SUPPLIER secondary_load; 13 | alter table NATION secondary_load; 14 | alter table REGION secondary_load; 15 | alter table PART secondary_load; 16 | alter table PARTSUPP secondary_load; 17 | -------------------------------------------------------------------------------- /TPCH/hq17.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPCH Query 17 - Small-Quantity-Order-Revenue Query 7 | SELECT 8 | SUM(l_extendedprice) / 7.0 AS avg_yearly 9 | FROM 10 | LINEITEM, 11 | PART 12 | WHERE 13 | p_partkey = l_partkey 14 | AND p_brand = 'Brand#23' 15 | AND p_container = 'MED BOX' 16 | AND l_quantity < ( 17 | SELECT 18 | 0.2 * AVG(l_quantity) 19 | FROM 20 | LINEITEM 21 | WHERE 22 | l_partkey = p_partkey 23 | ); -------------------------------------------------------------------------------- /TPCH/hq3.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 3 - Shipping Priority 7 | SELECT 8 | l_orderkey, 9 | SUM(l_extendedprice * (1 - l_discount)) AS revenue, 10 | o_orderdate, 11 | o_shippriority 12 | FROM 13 | CUSTOMER, 14 | ORDERS, 15 | LINEITEM 16 | WHERE 17 | c_mktsegment = 'BUILDING' 18 | AND c_custkey = o_custkey 19 | AND l_orderkey = o_orderkey 20 | AND o_orderdate < DATE '1995-03-15' 21 | AND l_shipdate > DATE '1995-03-15' 22 | GROUP BY l_orderkey , o_orderdate , o_shippriority 23 | ORDER BY revenue DESC , o_orderdate 24 | LIMIT 10; -------------------------------------------------------------------------------- /TPCH/hq5.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 5 - Local Supplier Volume 7 | SELECT 8 | n_name, SUM(l_extendedprice * (1 - l_discount)) AS revenue 9 | FROM 10 | CUSTOMER, 11 | ORDERS, 12 | LINEITEM, 13 | SUPPLIER, 14 | NATION, 15 | REGION 16 | WHERE 17 | c_custkey = o_custkey 18 | AND l_orderkey = o_orderkey 19 | AND l_suppkey = s_suppkey 20 | AND c_nationkey = s_nationkey 21 | AND s_nationkey = n_nationkey 22 | AND n_regionkey = r_regionkey 23 | AND r_name = 'ASIA' 24 | AND o_orderdate >= DATE '1994-01-01' 25 | AND o_orderdate < DATE '1994-01-01' + INTERVAL '1' YEAR 26 | GROUP BY n_name 27 | ORDER BY revenue DESC; 28 | -------------------------------------------------------------------------------- /TPCH/hq1.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 1 - Pricing Summary Report 7 | SELECT 8 | l_returnflag, 9 | l_linestatus, 10 | SUM(l_quantity) AS sum_qty, 11 | SUM(l_extendedprice) AS sum_base_price, 12 | SUM(l_extendedprice * (1 - l_discount)) AS sum_disc_price, 13 | SUM(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge, 14 | AVG(l_quantity) AS avg_qty, 15 | AVG(l_extendedprice) AS avg_price, 16 | AVG(l_discount) AS avg_disc, 17 | COUNT(*) AS count_order 18 | FROM 19 | LINEITEM 20 | WHERE 21 | l_shipdate <= DATE '1998-12-01' - INTERVAL '90' DAY 22 | GROUP BY l_returnflag , l_linestatus 23 | ORDER BY l_returnflag , l_linestatus; -------------------------------------------------------------------------------- /TPCH/hq15.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 15 - Top Supplier Query 7 | WITH REVENUE0 AS ( 8 | SELECT 9 | L_SUPPKEY AS SUPPLIER_NO, 10 | SUM(L_EXTENDEDPRICE * (1 - L_DISCOUNT)) AS TOTAL_REVENUE 11 | FROM 12 | LINEITEM 13 | WHERE 14 | L_SHIPDATE >= DATE '1996-01-01' 15 | AND L_SHIPDATE < DATE_ADD(DATE '1996-01-01', 16 | INTERVAL 3 MONTH) 17 | GROUP BY L_SUPPKEY 18 | ) 19 | SELECT 20 | S_SUPPKEY, S_NAME, S_ADDRESS, S_PHONE, TOTAL_REVENUE 21 | FROM 22 | SUPPLIER, 23 | REVENUE0 24 | WHERE 25 | S_SUPPKEY = SUPPLIER_NO 26 | AND TOTAL_REVENUE = (SELECT 27 | MAX(TOTAL_REVENUE) 28 | FROM 29 | REVENUE0) 30 | ORDER BY S_SUPPKEY; -------------------------------------------------------------------------------- /TPCH/hq18.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 18 - Large Volume Customer 7 | SELECT 8 | C_NAME, 9 | C_CUSTKEY, 10 | O_ORDERKEY, 11 | O_ORDERDATE, 12 | O_TOTALPRICE, 13 | SUM(L_QUANTITY) 14 | FROM 15 | ORDERS, 16 | CUSTOMER, 17 | LINEITEM as L1 18 | WHERE 19 | O_ORDERKEY IN (SELECT 20 | L_ORDERKEY 21 | FROM 22 | LINEITEM as L2 23 | GROUP BY L_ORDERKEY 24 | HAVING SUM(L_QUANTITY) > 300) 25 | AND C_CUSTKEY = O_CUSTKEY 26 | AND O_ORDERKEY = L_ORDERKEY 27 | GROUP BY C_NAME , C_CUSTKEY , O_ORDERKEY , O_ORDERDATE , O_TOTALPRICE 28 | ORDER BY O_TOTALPRICE DESC , O_ORDERDATE 29 | LIMIT 100; 30 | -------------------------------------------------------------------------------- /TPCH/hq11.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 11 - Important Stock Identification 7 | SELECT 8 | PS_PARTKEY, SUM(PS_SUPPLYCOST * PS_AVAILQTY) AS VALUE 9 | FROM 10 | PARTSUPP, 11 | SUPPLIER, 12 | NATION 13 | WHERE 14 | PS_SUPPKEY = S_SUPPKEY 15 | AND S_NATIONKEY = N_NATIONKEY 16 | AND N_NAME = 'GERMANY' 17 | GROUP BY PS_PARTKEY 18 | HAVING SUM(PS_SUPPLYCOST * PS_AVAILQTY) > (SELECT 19 | SUM(PS_SUPPLYCOST * PS_AVAILQTY) * 0.0001 20 | FROM 21 | PARTSUPP, 22 | SUPPLIER, 23 | NATION 24 | WHERE 25 | PS_SUPPKEY = S_SUPPKEY 26 | AND S_NATIONKEY = N_NATIONKEY 27 | AND N_NAME = 'GERMANY') 28 | ORDER BY VALUE DESC; -------------------------------------------------------------------------------- /TPCH/hq16.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 16 - Parts/Suppplier Relationship 7 | SELECT 8 | P_BRAND, 9 | P_TYPE, 10 | P_SIZE, 11 | COUNT(DISTINCT PS_SUPPKEY) AS SUPPLIER_CNT 12 | FROM 13 | PARTSUPP, 14 | PART 15 | WHERE 16 | P_PARTKEY = PS_PARTKEY 17 | AND P_BRAND <> 'Brand#45' 18 | AND P_TYPE NOT LIKE 'MEDIUM POLISHED%' 19 | AND P_SIZE IN (49 , 14, 23, 45, 19, 3, 36, 9) 20 | AND PS_SUPPKEY NOT IN (SELECT 21 | S_SUPPKEY 22 | FROM 23 | SUPPLIER 24 | WHERE 25 | S_COMMENT LIKE '%Customer%Complaints%') 26 | GROUP BY P_BRAND , P_TYPE , P_SIZE 27 | ORDER BY SUPPLIER_CNT DESC , P_BRAND , P_TYPE , P_SIZE; -------------------------------------------------------------------------------- /TPCH/hq10.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 10 - Returned Item Reporting 7 | SELECT 8 | c_custkey, 9 | c_name, 10 | SUM(l_extendedprice * (1 - l_discount)) AS revenue, 11 | c_acctbal, 12 | n_name, 13 | c_address, 14 | c_phone, 15 | c_comment 16 | FROM 17 | CUSTOMER, 18 | ORDERS, 19 | LINEITEM, 20 | NATION 21 | WHERE 22 | c_custkey = o_custkey 23 | AND l_orderkey = o_orderkey 24 | AND o_orderdate >= DATE '1993-10-01' 25 | AND o_orderdate < DATE '1993-10-01' + INTERVAL '3' MONTH 26 | AND l_returnflag = 'R' 27 | AND c_nationkey = n_nationkey 28 | GROUP BY c_custkey , c_name , c_acctbal , c_phone , n_name , c_address , c_comment 29 | ORDER BY revenue DESC 30 | LIMIT 20; -------------------------------------------------------------------------------- /TPCH/hq9.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 9 - Product Type Profit Measure 7 | SELECT 8 | nation, o_year, SUM(amount) AS sum_profit 9 | FROM 10 | (SELECT 11 | n_name AS nation, 12 | YEAR(o_ORDERdate) AS o_year, 13 | l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity AS amount 14 | FROM 15 | PART, 16 | SUPPLIER, 17 | LINEITEM, 18 | PARTSUPP, 19 | ORDERS, 20 | NATION 21 | WHERE 22 | s_suppkey = l_suppkey 23 | AND ps_suppkey = l_suppkey 24 | AND ps_partkey = l_partkey 25 | AND p_partkey = l_partkey 26 | AND o_orderkey = l_orderkey 27 | AND s_nationkey = n_nationkey 28 | AND p_name LIKE '%green%') AS profit 29 | GROUP BY nation , o_year 30 | ORDER BY nation , o_year DESC; -------------------------------------------------------------------------------- /TPCH/hq22.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 22 - Global Sales Opprtunity 7 | SELECT 8 | CNTRYCODE, COUNT(*) AS NUMCUST, SUM(C_ACCTBAL) AS TOTACCTBAL 9 | FROM 10 | (SELECT 11 | SUBSTRING(C_PHONE FROM 1 FOR 2) AS CNTRYCODE, C_ACCTBAL 12 | FROM 13 | CUSTOMER 14 | WHERE 15 | SUBSTRING(C_PHONE FROM 1 FOR 2) IN ('13' , '31', '23', '29', '30', '18', '17') 16 | AND C_ACCTBAL > (SELECT 17 | AVG(C_ACCTBAL) 18 | FROM 19 | CUSTOMER 20 | WHERE 21 | C_ACCTBAL > 0.00 22 | AND SUBSTRING(C_PHONE FROM 1 FOR 2) IN ('13' , '31', '23', '29', '30', '18', '17')) 23 | AND NOT EXISTS( SELECT 24 | * 25 | FROM 26 | ORDERS 27 | WHERE 28 | O_CUSTKEY = C_CUSTKEY)) AS CUSTSALE 29 | GROUP BY CNTRYCODE 30 | ORDER BY CNTRYCODE; -------------------------------------------------------------------------------- /TPCH/hq20.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPCH Query 20 - Potential Part Promotions Query 7 | SELECT 8 | s_name, s_address 9 | FROM 10 | SUPPLIER, 11 | NATION 12 | WHERE 13 | s_suppkey IN ( 14 | SELECT 15 | ps_suppkey 16 | FROM 17 | PART, 18 | PARTSUPP 19 | WHERE 20 | ps_partkey = p_partkey 21 | AND p_name LIKE 'forest%' 22 | AND ps_availqty > ( 23 | SELECT 24 | 0.5 * SUM(l_quantity) 25 | FROM 26 | LINEITEM 27 | WHERE 28 | l_partkey = ps_partkey 29 | AND l_suppkey = ps_suppkey 30 | AND l_shipdate >= '1994-01-01' 31 | AND l_shipdate < '1995-01-01' ) ) 32 | AND s_nationkey = n_nationkey 33 | AND n_name = 'CANADA' 34 | ORDER BY s_name; 35 | -------------------------------------------------------------------------------- /TPCH/hq12.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 12 -Shipping Modes and Order Priority 7 | SELECT 8 | l_shipmode, 9 | SUM(CASE 10 | WHEN 11 | o_orderpriority = '1-URGENT' 12 | OR o_orderpriority = '2-HIGH' 13 | THEN 14 | 1 15 | ELSE 0 16 | END) AS high_line_count, 17 | SUM(CASE 18 | WHEN 19 | o_orderpriority <> '1-URGENT' 20 | AND o_orderpriority <> '2-HIGH' 21 | THEN 22 | 1 23 | ELSE 0 24 | END) AS low_line_count 25 | FROM 26 | ORDERS, 27 | LINEITEM 28 | WHERE 29 | o_orderkey = l_orderkey 30 | AND l_shipmode IN ('MAIL' , 'SHIP') 31 | AND l_commitdate < l_receiptdate 32 | AND l_shipdate < l_commitdate 33 | AND l_receiptdate >= DATE '1994-01-01' 34 | AND l_receiptdate < DATE '1994-01-01' + INTERVAL '1' YEAR 35 | GROUP BY l_shipmode 36 | ORDER BY l_shipmode; -------------------------------------------------------------------------------- /TPCH/hq21.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 21 - Suppliers Who Kept Orders Waiting 7 | SELECT 8 | S_NAME, COUNT(*) AS NUMWAIT 9 | FROM 10 | SUPPLIER, 11 | LINEITEM L1, 12 | ORDERS, 13 | NATION 14 | WHERE 15 | S_SUPPKEY = L1.L_SUPPKEY 16 | AND O_ORDERKEY = L1.L_ORDERKEY 17 | AND O_ORDERSTATUS = 'F' 18 | AND L1.L_RECEIPTDATE > L1.L_COMMITDATE 19 | AND EXISTS( SELECT 20 | * 21 | FROM 22 | LINEITEM L2 23 | WHERE 24 | L2.L_ORDERKEY = L1.L_ORDERKEY 25 | AND L2.L_SUPPKEY <> L1.L_SUPPKEY) 26 | AND NOT EXISTS( SELECT 27 | * 28 | FROM 29 | LINEITEM L3 30 | WHERE 31 | L3.L_ORDERKEY = L1.L_ORDERKEY 32 | AND L3.L_SUPPKEY <> L1.L_SUPPKEY 33 | AND L3.L_RECEIPTDATE > L3.L_COMMITDATE) 34 | AND S_NATIONKEY = N_NATIONKEY 35 | AND N_NAME = 'SAUDI ARABIA' 36 | GROUP BY S_NAME 37 | ORDER BY NUMWAIT DESC , S_NAME 38 | LIMIT 100; -------------------------------------------------------------------------------- /TPCH/hq7.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPCH Query 7 - Volume Shipping 7 | SELECT 8 | supp_nation, cust_nation, l_year, SUM(volume) AS revenue 9 | FROM 10 | (SELECT 11 | n1.n_name AS supp_nation, 12 | n2.n_name AS cust_nation, 13 | EXTRACT(YEAR FROM l_shipdate) AS l_year, 14 | l_extendedprice * (1 - l_discount) AS volume 15 | FROM 16 | SUPPLIER, 17 | LINEITEM, 18 | ORDERS, 19 | CUSTOMER, 20 | NATION n1, 21 | NATION n2 22 | WHERE 23 | s_suppkey = l_suppkey 24 | AND o_orderkey = l_orderkey 25 | AND c_custkey = o_custkey 26 | AND s_nationkey = n1.n_nationkey 27 | AND c_nationkey = n2.n_nationkey 28 | AND ((n1.n_name = 'FRANCE' 29 | AND n2.n_name = 'GERMANY') 30 | OR (n1.n_name = 'GERMANY' 31 | AND n2.n_name = 'FRANCE')) 32 | AND l_shipdate BETWEEN DATE '1995-01-01' AND DATE '1996-12-31') AS shipping 33 | GROUP BY supp_nation , cust_nation , l_year 34 | ORDER BY supp_nation , cust_nation , l_year; -------------------------------------------------------------------------------- /TPCH/hq8.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 8 - National Market Share 7 | SELECT 8 | o_year, 9 | SUM(CASE 10 | WHEN nation = 'BRAZIL' THEN volume 11 | ELSE 0 12 | END) / SUM(volume) AS mkt_share 13 | FROM 14 | (SELECT 15 | EXTRACT(YEAR FROM o_orderdate) AS o_year, 16 | l_extendedprice * (1 - l_discount) AS volume, 17 | n2.n_name AS nation 18 | FROM 19 | PART, 20 | SUPPLIER, 21 | LINEITEM, 22 | ORDERS, 23 | CUSTOMER, 24 | NATION n1, 25 | NATION n2, 26 | REGION 27 | WHERE 28 | p_partkey = l_partkey 29 | AND s_suppkey = l_suppkey 30 | AND l_orderkey = o_orderkey 31 | AND o_custkey = c_custkey 32 | AND c_nationkey = n1.n_nationkey 33 | AND n1.n_regionkey = r_regionkey 34 | AND r_name = 'AMERICA' 35 | AND s_nationkey = n2.n_nationkey 36 | AND o_orderdate BETWEEN DATE '1995-01-01' AND DATE '1996-12-31' 37 | AND p_type = 'ECONOMY ANODIZED STEEL') AS all_nations 38 | GROUP BY o_year 39 | ORDER BY o_year; -------------------------------------------------------------------------------- /TPCH/hq2.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 2 - Minimum Cost Supplier Query 7 | SELECT 8 | s_acctbal, s_name, n_name, p_partkey, p_mfgr, 9 | s_address, s_phone, s_comment 10 | FROM 11 | PART, 12 | SUPPLIER, 13 | PARTSUPP, 14 | NATION, 15 | REGION 16 | WHERE 17 | p_partkey = ps_partkey 18 | AND s_suppkey = ps_suppkey 19 | AND s_nationkey = n_nationkey 20 | AND n_regionkey = r_regionkey 21 | AND p_size = 15 22 | AND p_type LIKE '%BRASS' 23 | AND r_name = 'EUROPE' 24 | AND ps_supplycost = ( 25 | SELECT 26 | MIN(ps_supplycost) 27 | FROM 28 | PARTSUPP, 29 | SUPPLIER, 30 | NATION, 31 | REGION 32 | WHERE 33 | s_suppkey = ps_suppkey 34 | AND s_nationkey = n_nationkey 35 | AND n_regionkey = r_regionkey 36 | AND p_partkey = ps_partkey 37 | AND r_name = 'EUROPE' 38 | ) 39 | ORDER BY 40 | s_acctbal desc, n_name, s_name, p_partkey 41 | LIMIT 100; 42 | -------------------------------------------------------------------------------- /TPCH/hq19.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- TPC-H Query 19 - Discounted Revenue 7 | SELECT 8 | SUM(l_extendedprice * (1 - l_discount)) AS revenue 9 | FROM 10 | LINEITEM, 11 | PART 12 | WHERE 13 | (p_partkey = l_partkey 14 | AND p_brand = 'Brand#12' 15 | AND p_container IN ('SM CASE' , 'SM BOX', 'SM PACK', 'SM PKG') 16 | AND l_quantity >= 1 17 | AND l_quantity <= 1 + 10 18 | AND p_size BETWEEN 1 AND 5 19 | AND l_shipmode IN ('AIR' , 'AIR REG') 20 | AND l_shipinstruct = 'DELIVER IN PERSON') 21 | OR (p_partkey = l_partkey 22 | AND p_brand = 'Brand#23' 23 | AND p_container IN ('MED BAG' , 'MED BOX', 'MED PKG', 'MED PACK') 24 | AND l_quantity >= 10 25 | AND l_quantity <= 10 + 10 26 | AND p_size BETWEEN 1 AND 10 27 | AND l_shipmode IN ('AIR' , 'AIR REG') 28 | AND l_shipinstruct = 'DELIVER IN PERSON') 29 | OR (p_partkey = l_partkey 30 | AND p_brand = 'Brand#34' 31 | AND p_container IN ('LG CASE' , 'LG BOX', 'LG PACK', 'LG PKG') 32 | AND l_quantity >= 20 33 | AND l_quantity <= 20 + 10 34 | AND p_size BETWEEN 1 AND 15 35 | AND l_shipmode IN ('AIR' , 'AIR REG') 36 | AND l_shipinstruct = 'DELIVER IN PERSON'); -------------------------------------------------------------------------------- /SECURITY.md: -------------------------------------------------------------------------------- 1 | # Reporting security vulnerabilities 2 | 3 | Oracle values the independent security research community and believes that 4 | responsible disclosure of security vulnerabilities helps us ensure the security 5 | and privacy of all our users. 6 | 7 | Please do NOT raise a GitHub Issue to report a security vulnerability. If you 8 | believe you have found a security vulnerability, please submit a report to 9 | [secalert_us@oracle.com][1] preferably with a proof of concept. Please review 10 | some additional information on [how to report security vulnerabilities to Oracle][2]. 11 | We encourage people who contact Oracle Security to use email encryption using 12 | [our encryption key][3]. 13 | 14 | We ask that you do not use other channels or contact the project maintainers 15 | directly. 16 | 17 | Non-vulnerability related security issues including ideas for new or improved 18 | security features are welcome on GitHub Issues. 19 | 20 | ## Security updates, alerts and bulletins 21 | 22 | Security updates will be released on a regular cadence. Many of our projects 23 | will typically release security fixes in conjunction with the 24 | Oracle Critical Patch Update program. Additional 25 | information, including past advisories, is available on our [security alerts][4] 26 | page. 27 | 28 | ## Security-related information 29 | 30 | We will provide security related information such as a threat model, considerations 31 | for secure use, or any known security issues in our documentation. Please note 32 | that labs and sample code are intended to demonstrate a concept and may not be 33 | sufficiently hardened for production use. 34 | 35 | [1]: mailto:secalert_us@oracle.com 36 | [2]: https://www.oracle.com/corporate/security-practices/assurance/vulnerability/reporting.html 37 | [3]: https://www.oracle.com/security-alerts/encryptionkey.html 38 | [4]: https://www.oracle.com/security-alerts/ 39 | -------------------------------------------------------------------------------- /LICENSE.txt: -------------------------------------------------------------------------------- 1 | Copyright (c) 2020, 2023 Oracle and/or its affiliates 2 | 3 | The Universal Permissive License (UPL), Version 1.0 4 | 5 | Subject to the condition set forth below, permission is hereby granted to any 6 | person obtaining a copy of this software, associated documentation and/or data 7 | (collectively the "Software"), free of charge and under any and all copyright 8 | rights in the Software, and any and all patent rights owned or freely 9 | licensable by each licensor hereunder covering either (i) the unmodified 10 | Software as contributed to or provided by such licensor, or (ii) the Larger 11 | Works (as defined below), to deal in both 12 | 13 | (a) the Software, and 14 | (b) any piece of software and/or hardware listed in the lrgrwrks.txt file if 15 | one is included with the Software (each a "Larger Work" to which the Software 16 | is contributed by such licensors), 17 | 18 | without restriction, including without limitation the rights to copy, create 19 | derivative works of, display, perform, and distribute the Software and make, 20 | use, sell, offer for sale, import, export, have made, and have sold the 21 | Software and the Larger Work(s), and to sublicense the foregoing rights on 22 | either these or other terms. 23 | 24 | This license is subject to the following condition: 25 | The above copyright notice and either this complete permission notice or at 26 | a minimum a reference to the UPL must be included in all copies or 27 | substantial portions of the Software. 28 | 29 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 30 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 31 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 32 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 33 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 34 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 35 | SOFTWARE. 36 | -------------------------------------------------------------------------------- /TPCH/create_tables.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- Coypright (c) 2020, Transaction Processing Performance Council 5 | 6 | -- using database tpch_1024 as an example 7 | -- ascii_bin character set and collation used for benchmarking performance 8 | 9 | create database tpch_1024; 10 | alter database tpch_1024 CHARACTER SET ascii COLLATE ascii_bin; 11 | use tpch_1024; 12 | 13 | CREATE TABLE NATION ( N_NATIONKEY INTEGER NOT NULL, 14 | N_NAME CHAR(25) NOT NULL, 15 | N_REGIONKEY INTEGER NOT NULL, 16 | N_COMMENT VARCHAR(152), 17 | PRIMARY KEY (N_NATIONKEY)); 18 | 19 | CREATE TABLE REGION ( R_REGIONKEY INTEGER NOT NULL, 20 | R_NAME CHAR(25) NOT NULL, 21 | R_COMMENT VARCHAR(152), 22 | PRIMARY KEY (R_REGIONKEY)); 23 | 24 | CREATE TABLE PART ( P_PARTKEY INTEGER NOT NULL, 25 | P_NAME VARCHAR(55) NOT NULL, 26 | P_MFGR CHAR(25) NOT NULL, 27 | P_BRAND CHAR(10) NOT NULL, 28 | P_TYPE VARCHAR(25) NOT NULL, 29 | P_SIZE INTEGER NOT NULL, 30 | P_CONTAINER CHAR(10) NOT NULL, 31 | P_RETAILPRICE DECIMAL(15,2) NOT NULL, 32 | P_COMMENT VARCHAR(23) NOT NULL, 33 | PRIMARY KEY (P_PARTKEY)); 34 | 35 | CREATE TABLE SUPPLIER ( S_SUPPKEY INTEGER NOT NULL, 36 | S_NAME CHAR(25) NOT NULL, 37 | S_ADDRESS VARCHAR(40) NOT NULL, 38 | S_NATIONKEY INTEGER NOT NULL, 39 | S_PHONE CHAR(15) NOT NULL, 40 | S_ACCTBAL DECIMAL(15,2) NOT NULL, 41 | S_COMMENT VARCHAR(101) NOT NULL, 42 | PRIMARY KEY (S_SUPPKEY)); 43 | 44 | CREATE TABLE PARTSUPP ( PS_PARTKEY INTEGER NOT NULL, 45 | PS_SUPPKEY INTEGER NOT NULL, 46 | PS_AVAILQTY INTEGER NOT NULL, 47 | PS_SUPPLYCOST DECIMAL(15,2) NOT NULL, 48 | PS_COMMENT VARCHAR(199) NOT NULL, 49 | PRIMARY KEY (PS_PARTKEY, PS_SUPPKEY)); 50 | 51 | CREATE TABLE CUSTOMER ( C_CUSTKEY INTEGER NOT NULL, 52 | C_NAME VARCHAR(25) NOT NULL, 53 | C_ADDRESS VARCHAR(40) NOT NULL, 54 | C_NATIONKEY INTEGER NOT NULL, 55 | C_PHONE CHAR(15) NOT NULL, 56 | C_ACCTBAL DECIMAL(15,2) NOT NULL, 57 | C_MKTSEGMENT CHAR(10) NOT NULL, 58 | C_COMMENT VARCHAR(117) NOT NULL, 59 | PRIMARY KEY (C_CUSTKEY)); 60 | 61 | CREATE TABLE ORDERS ( O_ORDERKEY BIGINT NOT NULL, 62 | O_CUSTKEY INTEGER NOT NULL, 63 | O_ORDERSTATUS CHAR(1) NOT NULL, 64 | O_TOTALPRICE DECIMAL(15,2) NOT NULL, 65 | O_ORDERDATE DATE NOT NULL, 66 | O_ORDERPRIORITY CHAR(15) NOT NULL, 67 | O_CLERK CHAR(15) NOT NULL, 68 | O_SHIPPRIORITY INTEGER NOT NULL, 69 | O_COMMENT VARCHAR(79) NOT NULL, 70 | PRIMARY KEY (O_ORDERKEY)); 71 | 72 | CREATE TABLE LINEITEM ( L_ORDERKEY BIGINT NOT NULL, 73 | L_PARTKEY INTEGER NOT NULL, 74 | L_SUPPKEY INTEGER NOT NULL, 75 | L_LINENUMBER INTEGER NOT NULL, 76 | L_QUANTITY DECIMAL(15,2) NOT NULL, 77 | L_EXTENDEDPRICE DECIMAL(15,2) NOT NULL, 78 | L_DISCOUNT DECIMAL(15,2) NOT NULL, 79 | L_TAX DECIMAL(15,2) NOT NULL, 80 | L_RETURNFLAG CHAR(1) NOT NULL, 81 | L_LINESTATUS CHAR(1) NOT NULL, 82 | L_SHIPDATE DATE NOT NULL, 83 | L_COMMITDATE DATE NOT NULL, 84 | L_RECEIPTDATE DATE NOT NULL, 85 | L_SHIPINSTRUCT CHAR(25) NOT NULL, 86 | L_SHIPMODE CHAR(10) NOT NULL, 87 | L_COMMENT VARCHAR(44) NOT NULL, 88 | PRIMARY KEY (L_ORDERKEY, L_LINENUMBER)) 89 | PARTITION BY KEY() 90 | PARTITIONS 128; 91 | -------------------------------------------------------------------------------- /HeatWave/secondary_load.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2020, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ 3 | 4 | -- tpch reset comments 5 | alter table NATION secondary_engine NULL; 6 | alter table REGION secondary_engine NULL; 7 | alter table LINEITEM secondary_engine NULL; 8 | alter table SUPPLIER secondary_engine NULL; 9 | alter table ORDERS secondary_engine NULL; 10 | alter table CUSTOMER secondary_engine NULL; 11 | alter table PART secondary_engine NULL; 12 | alter table PARTSUPP secondary_engine NULL; 13 | 14 | -- optimal encodings 15 | alter table NATION change N_NAME N_NAME CHAR(25) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 16 | alter table NATION change N_COMMENT N_COMMENT VARCHAR(152) COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 17 | alter table REGION change R_NAME R_NAME CHAR(25) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 18 | alter table REGION change R_COMMENT R_COMMENT VARCHAR(152) COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 19 | alter table PART change P_NAME P_NAME VARCHAR(55) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 20 | alter table PART change P_MFGR P_MFGR CHAR(25) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 21 | alter table PART change P_BRAND P_BRAND CHAR(10) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 22 | alter table PART change P_TYPE P_TYPE VARCHAR(25) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 23 | alter table PART change P_CONTAINER P_CONTAINER CHAR(10) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 24 | alter table PART change P_COMMENT P_COMMENT VARCHAR(23) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 25 | alter table SUPPLIER change S_NAME S_NAME CHAR(25) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 26 | alter table SUPPLIER change S_ADDRESS S_ADDRESS VARCHAR(40) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 27 | alter table SUPPLIER change S_PHONE S_PHONE CHAR(15) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 28 | alter table SUPPLIER change S_COMMENT S_COMMENT VARCHAR(101) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 29 | alter table PARTSUPP change PS_COMMENT PS_COMMENT VARCHAR(199) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 30 | alter table CUSTOMER change C_NAME C_NAME VARCHAR(25) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 31 | alter table CUSTOMER change C_ADDRESS C_ADDRESS VARCHAR(40) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 32 | alter table CUSTOMER change C_PHONE C_PHONE CHAR(15) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 33 | alter table CUSTOMER change C_MKTSEGMENT C_MKTSEGMENT CHAR(10) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 34 | alter table CUSTOMER change C_COMMENT C_COMMENT VARCHAR(117) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 35 | alter table ORDERS change O_ORDERSTATUS O_ORDERSTATUS CHAR(1) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 36 | alter table ORDERS change O_ORDERPRIORITY O_ORDERPRIORITY CHAR(15) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 37 | alter table ORDERS change O_CLERK O_CLERK CHAR(15) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 38 | alter table ORDERS change O_COMMENT O_COMMENT VARCHAR(79) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 39 | alter table LINEITEM change L_RETURNFLAG L_RETURNFLAG CHAR(1) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 40 | alter table LINEITEM change L_LINESTATUS L_LINESTATUS CHAR(1) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 41 | alter table LINEITEM change L_SHIPINSTRUCT L_SHIPINSTRUCT CHAR(25) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 42 | alter table LINEITEM change L_COMMENT L_COMMENT VARCHAR(44) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 43 | alter table LINEITEM change L_SHIPMODE L_SHIPMODE CHAR(10) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=SORTED'; 44 | 45 | alter table CUSTOMER change C_PHONE C_PHONE CHAR(15) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=VARLEN'; 46 | alter table ORDERS change O_COMMENT O_COMMENT VARCHAR(79) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=VARLEN'; 47 | alter table PART change P_NAME P_NAME VARCHAR(55) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=VARLEN'; 48 | alter table PART change P_TYPE P_TYPE VARCHAR(25) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=VARLEN'; 49 | alter table SUPPLIER change S_COMMENT S_COMMENT VARCHAR(101) NOT NULL COMMENT 'RAPID_COLUMN=ENCODING=VARLEN'; 50 | 51 | -- optimal data placement 52 | alter table LINEITEM change L_ORDERKEY L_ORDERKEY BIGINT NOT NULL COMMENT 'RAPID_COLUMN=DATA_PLACEMENT_KEY=1'; 53 | 54 | -- mark tables for RAPID 55 | alter table NATION secondary_engine RAPID; 56 | alter table REGION secondary_engine RAPID; 57 | alter table LINEITEM secondary_engine RAPID; 58 | alter table SUPPLIER secondary_engine RAPID; 59 | alter table ORDERS secondary_engine RAPID; 60 | alter table CUSTOMER secondary_engine RAPID; 61 | alter table PART secondary_engine RAPID; 62 | alter table PARTSUPP secondary_engine RAPID; 63 | 64 | -- Secondary Load 65 | -- Set Parallel reads threads to 32 66 | set innodb_parallel_read_threads=32; 67 | ALTER TABLE LINEITEM SECONDARY_LOAD; 68 | ALTER TABLE ORDERS SECONDARY_LOAD; 69 | ALTER TABLE CUSTOMER SECONDARY_LOAD; 70 | ALTER TABLE SUPPLIER SECONDARY_LOAD; 71 | ALTER TABLE NATION SECONDARY_LOAD; 72 | ALTER TABLE REGION SECONDARY_LOAD; 73 | ALTER TABLE PART SECONDARY_LOAD; 74 | ALTER TABLE PARTSUPP SECONDARY_LOAD; 75 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # HeatWave TPC-H 2 | 3 | MySQL HeatWave is a fully managed and highly scalable in-memory database service which provides a cost-efficient solution for 4 | OLTP, OLAP and Machine Learning. It is available on both Oracle Cloud Infrastructure (OCI) and Amazon Web Service (AWS). 5 | 6 | HeatWave is tightly integrated with MySQL database and is optimized for underlying infrastructure. 7 | You can run analytics on your MySQL data without requiring ETL and without any change to Your applications. Your 8 | applications connect to the HeatWave cluster through standard MySQL protocols. 9 | The MySQL Database is built on the MySQL Enterprise Edition Server, which allows developers to quickly create and deploy secure 10 | cloud native applications using the world's most popular open source database. 11 | 12 | MySQL HeatWave Lakehouse extends MySQL HeatWave to enable you to run analytics workloads on data stored in object storage 13 | at 100s of TB data scale. HeatWave Lakehouse provides the same high query performance as MySQL HeatWave, enables you to run 14 | queries across data from both MySQL and object storage, providing a great solution for your data warehouse and data lake use cases. 15 | 16 | This repository contains SQL scripts derived from [TPC Benchmark™H (TPC-H)][1]. The SQL scripts contain TPC-H schema 17 | generation statements and queries derived from TPC-H benchmark, specific for MySQL HeatWave and MySQL HeatWave Lakehouse. 18 | 19 | ## Software prerequisites: 20 | 1. [TPC-H data generation tool][2] to generate TPC-H dataset for workload sizes of your choice 21 | 2. [MySQL Shell][3] to import generated TPC-H dataset to MySQL Database System 22 | 23 | ## Required services: 24 | 1. [Oracle Cloud Infrastructure][9] 25 | 2. [MySQL HeatWave for OCI][4] or [MySQL HeatWave on AWS][5] 26 | 27 | ## Repository 28 | * [TPCH](TPCH) - a collection of scripts for TPC-H schema and queries specific to MySQL Database System 29 | * [HeatWave](HeatWave) - a collection of scripts to configure HeatWave to run TPC-H queries 30 | 31 | ## Getting started 32 | ### To run TPC-H queries in HeatWave 33 | 1. Generate TPC-H data using TPC-H data generation tool 34 | 2. Provision a MySQL Database System 35 | 3. Run [create_tables.sql](TPCH/create_tables.sql) to create TPC-H schema on MySQL Database System 36 | 4. Import TPC-H data generated to MySQL Database System. See [MySQL Shell Parallel Table Import Utility documentation][7] 37 | 5. Add a HeatWave cluster to MySQL Database System. See [HeatWave][8] documentation 38 | 6. Run [secondary_load.sql](HeatWave/secondary_load.sql) to configure and load data to HeatWave cluster 39 | 7. You are now ready to run the queries derived from TPC-H 40 | 41 | 42 | ### To run TPC-H queries in MySQL HeatWave Lakehouse 43 | 1. Generate TPC-H data using TPC-H data generation tool 44 | 2. Keep the generated data in an Object Store bucket in OCI (in the same region where the MySQL Database System will be provisioned). 45 | Note down the namespace and bucket information. 46 | 3. Provision a MySQL Database System. See [Getting Started with MySQL Database Service][6] 47 | 4. Add a HeatWave cluster to MySQL Database System. See [HeatWave][8] documentation 48 | 5. Run [create_tables_lakehouse.sql](TPCH/create_tables_lakehouse.sql) to create TPC-H schema for MySQL HeatWave Lakehouse on MySQL Database System. 49 | Make sure to fill in the appropriate **\**, **\**, **\** and **\** information in the script. 50 | 6. For larger scale TPC-H datasets, you might need to modify your table definitions in [create_tables_lakehouse.sql](TPCH/create_tables_lakehouse.sql) to account for larger data values (BIGINTS instead of INTEGER) in certain columns. 51 | 7. Run [secondary_load_lakehouse.sql](HeatWave/secondary_load_lakehouse.sql) to configure and load data to HeatWave cluster 52 | 8. You are now ready to run the queries derived from TPC-H 53 | 54 | [1]: http://www.tpc.org/tpch/ 55 | [2]: http://www.tpc.org/tpc_documents_current_versions/download_programs/tools-download-request5.asp?bm_type=TPC-H&bm_vers=2.18.0&mode=CURRENT-ONLY 56 | [3]: https://dev.mysql.com/downloads/shell/ 57 | [4]: https://docs.oracle.com/en-us/iaas/mysql-database/doc/heatwave.html 58 | [5]: https://dev.mysql.com/doc/heatwave-aws/en/ 59 | [6]: https://docs.cloud.oracle.com/en-us/iaas/mysql-database/doc/getting-started.html 60 | [7]: https://dev.mysql.com/doc/mysql-shell/8.0/en/mysql-shell-utilities-parallel-table.html 61 | [8]: https://docs.cloud.oracle.com/en-us/iaas/mysql-database/doc/mysql-analytics-engine.html 62 | [9]: https://docs.cloud.oracle.com/en-us/iaas/Content/home.htm 63 | 64 | TPC Benchmark™, TPC-H, QppH, QthH, and QphH are trademarks of the Transaction Processing Performance 65 | Council. 66 | 67 | All parties are granted permission to copy and distribute to any party without fee all or part of this material provided 68 | that: 1) copying and distribution is done for the primary purpose of disseminating TPC material; 2) the TPC 69 | copyright notice, the title of the publication, and its date appear, and notice is given that copying is by permission of 70 | the Transaction Processing Performance Council. 71 | 72 | Benchmark queries are derived from the TPC-H benchmark, but results are not comparable to published TPC-H benchmark results since they do not comply with the TPC-H specification. 73 | 74 | ## Contributing 75 | 76 | This project is not accepting external contributions at this time. For bugs or enhancement requests, please file a GitHub issue unless it’s security related. When filing a bug remember that the better written the bug is, the more likely it is to be fixed. If you think you’ve found a security vulnerability, do not raise a GitHub issue and follow the instructions in our [security policy](./SECURITY.md). 77 | 78 | ## Security 79 | 80 | Please consult the [security guide](./SECURITY.md) for our responsible security vulnerability disclosure process 81 | 82 | ## License 83 | 84 | Copyright (c) 2020, 2023 Oracle and/or its affiliates. 85 | 86 | Released under the Universal Permissive License v1.0 as shown at 87 | . 88 | -------------------------------------------------------------------------------- /TPCH/create_tables_lakehouse.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2022, Oracle and/or its affiliates. 2 | -- Licensed under the Universal Permissive License v 1.0 as shown as https://oss.oracle.com/licences/upl 3 | 4 | -- Copyright (c) 2022, Transaction Processing Performance Council 5 | 6 | -- using database tpch_1024 as an example 7 | -- ascii_bin character set and collation used for benchmarking performance 8 | 9 | create database tpch_1024; 10 | alter database tpch_1024 CHARACTER SET ascii COLLATE ascii_bin; 11 | use tpch_1024; 12 | 13 | 14 | -- Create lakehouse tables - source data in OCI object store 15 | 16 | CREATE TABLE LINEITEM ( L_ORDERKEY BIGINT NOT NULL, 17 | L_PARTKEY INTEGER NOT NULL, 18 | L_SUPPKEY INTEGER NOT NULL, 19 | L_LINENUMBER INTEGER NOT NULL, 20 | L_QUANTITY DECIMAL(15,2) NOT NULL, 21 | L_EXTENDEDPRICE DECIMAL(15,2) NOT NULL, 22 | L_DISCOUNT DECIMAL(15,2) NOT NULL, 23 | L_TAX DECIMAL(15,2) NOT NULL, 24 | L_RETURNFLAG CHAR(1) NOT NULL, 25 | L_LINESTATUS CHAR(1) NOT NULL, 26 | L_SHIPDATE DATE NOT NULL, 27 | L_COMMITDATE DATE NOT NULL, 28 | L_RECEIPTDATE DATE NOT NULL, 29 | L_SHIPINSTRUCT CHAR(25) NOT NULL, 30 | L_SHIPMODE CHAR(10) NOT NULL, 31 | L_COMMENT VARCHAR(44) NOT NULL, 32 | PRIMARY KEY (L_ORDERKEY, L_LINENUMBER)) 33 | ENGINE=lakehouse 34 | secondary_engine=rapid 35 | ENGINE_ATTRIBUTE='{"file": 36 | [{"region":"", 37 | "namespace":"", 38 | "bucket":"", 39 | "name":""}]}'; 40 | 41 | 42 | CREATE TABLE ORDERS ( O_ORDERKEY BIGINT NOT NULL, 43 | O_CUSTKEY INTEGER NOT NULL, 44 | O_ORDERSTATUS CHAR(1) NOT NULL, 45 | O_TOTALPRICE DECIMAL(15,2) NOT NULL, 46 | O_ORDERDATE DATE NOT NULL, 47 | O_ORDERPRIORITY CHAR(15) NOT NULL, 48 | O_CLERK CHAR(15) NOT NULL, 49 | O_SHIPPRIORITY INTEGER NOT NULL, 50 | O_COMMENT VARCHAR(79) NOT NULL, 51 | PRIMARY KEY (O_ORDERKEY)) 52 | ENGINE=lakehouse 53 | secondary_engine=rapid 54 | ENGINE_ATTRIBUTE='{"file": 55 | [{"region":"", 56 | "namespace":"", 57 | "bucket":"", 58 | "name":""}]}'; 59 | 60 | 61 | create table CUSTOMER ( C_CUSTKEY INTEGER NOT NULL, 62 | C_NAME VARCHAR(25) NOT NULL, 63 | C_ADDRESS VARCHAR(40) NOT NULL, 64 | C_NATIONKEY INTEGER NOT NULL, 65 | C_PHONE CHAR(15) NOT NULL, 66 | C_ACCTBAL DECIMAL(15,2) NOT NULL, 67 | C_MKTSEGMENT CHAR(10) NOT NULL, 68 | C_COMMENT VARCHAR(117) NOT NULL, 69 | PRIMARY KEY (C_CUSTKEY)) 70 | ENGINE=lakehouse 71 | secondary_engine=rapid 72 | ENGINE_ATTRIBUTE='{"file": 73 | [{"region":"", 74 | "namespace":"", 75 | "bucket":"", 76 | "name":""}]}'; 77 | 78 | 79 | CREATE TABLE SUPPLIER ( S_SUPPKEY INTEGER NOT NULL, 80 | S_NAME CHAR(25) NOT NULL, 81 | S_ADDRESS VARCHAR(40) NOT NULL, 82 | S_NATIONKEY INTEGER NOT NULL, 83 | S_PHONE CHAR(15) NOT NULL, 84 | S_ACCTBAL DECIMAL(15,2) NOT NULL, 85 | S_COMMENT VARCHAR(101) NOT NULL, 86 | PRIMARY KEY (S_SUPPKEY)) 87 | ENGINE=lakehouse 88 | secondary_engine=rapid 89 | ENGINE_ATTRIBUTE='{"file": 90 | [{"region":"", 91 | "namespace":"", 92 | "bucket":"", 93 | "name":""}]}'; 94 | 95 | 96 | CREATE TABLE NATION ( N_NATIONKEY INTEGER NOT NULL, 97 | N_NAME CHAR(25) NOT NULL, 98 | N_REGIONKEY INTEGER NOT NULL, 99 | N_COMMENT VARCHAR(152) NOT NULL, 100 | PRIMARY KEY (N_NATIONKEY)) 101 | ENGINE=lakehouse 102 | secondary_engine=rapid 103 | ENGINE_ATTRIBUTE='{"file": 104 | [{"region":"", 105 | "namespace":"", 106 | "bucket":"", 107 | "name":""}]}'; 108 | 109 | CREATE TABLE REGION ( R_REGIONKEY INTEGER NOT NULL, 110 | R_NAME CHAR(25) NOT NULL, 111 | R_COMMENT VARCHAR(152) NOT NULL, 112 | PRIMARY KEY (R_REGIONKEY)) 113 | ENGINE=lakehouse 114 | secondary_engine=rapid 115 | ENGINE_ATTRIBUTE='{"file": 116 | [{"region":"", 117 | "namespace":"", 118 | "bucket":"", 119 | "name":""}]}'; 120 | 121 | 122 | CREATE TABLE PART ( P_PARTKEY INTEGER NOT NULL, 123 | P_NAME VARCHAR(55) NOT NULL, 124 | P_MFGR CHAR(25) NOT NULL, 125 | P_BRAND CHAR(10) NOT NULL, 126 | P_TYPE VARCHAR(25) NOT NULL, 127 | P_SIZE INTEGER NOT NULL, 128 | P_CONTAINER CHAR(10) NOT NULL, 129 | P_RETAILPRICE DECIMAL(15,2) NOT NULL, 130 | P_COMMENT VARCHAR(23) NOT NULL, 131 | PRIMARY KEY (P_PARTKEY)) 132 | ENGINE=lakehouse 133 | secondary_engine=rapid 134 | ENGINE_ATTRIBUTE='{"file": 135 | [{"region":"", 136 | "namespace":"", 137 | "bucket":"", 138 | "name":""}]}'; 139 | 140 | 141 | CREATE TABLE PARTSUPP ( PS_PARTKEY INTEGER NOT NULL, 142 | PS_SUPPKEY INTEGER NOT NULL, 143 | PS_AVAILQTY INTEGER NOT NULL, 144 | PS_SUPPLYCOST DECIMAL(15,2) NOT NULL, 145 | PS_COMMENT VARCHAR(199) NOT NULL, 146 | PRIMARY KEY (PS_PARTKEY, PS_SUPPKEY)) 147 | ENGINE=lakehouse 148 | secondary_engine=rapid 149 | ENGINE_ATTRIBUTE='{"file": 150 | [{"region":"", 151 | "namespace":"", 152 | "bucket":"", 153 | "name":""}]}'; 154 | 155 | 156 | 157 | 158 | 159 | 160 | 161 | --------------------------------------------------------------------------------