├── 1.sql ├── 10.sql ├── 11.sql ├── 12.sql ├── 13.sql ├── 14.sql ├── 15.sql ├── 16.sql ├── 17.sql ├── 18.sql ├── 19.sql ├── 2.sql ├── 20.sql ├── 21.sql ├── 22.sql ├── 3.sql ├── 4.sql ├── 5.sql ├── 6.sql ├── 7.sql ├── 8.sql ├── 9.sql └── README.md /1.sql: -------------------------------------------------------------------------------- 1 | select l_returnflag, l_linestatus, sum(l_quantity) as sum_qty, sum(l_extendedprice) as sum_base_price, sum(l_extendedprice * (1 - l_discount)) as sum_disc_price, sum(l_extendedprice * (1 - l_discount) * (1 + l_tax)) as sum_charge, avg(l_quantity) as avg_qty, avg(l_extendedprice) as avg_price, avg(l_discount) as avg_disc, count(*) as count_order from LINEITEM where l_shipdate <= date '1998-12-01' - interval '108' day group by l_returnflag, l_linestatus order by l_returnflag, l_linestatus; 2 | -------------------------------------------------------------------------------- /10.sql: -------------------------------------------------------------------------------- 1 | select c_custkey, 2 | c_name, 3 | sum(l_extendedprice * (1 - l_discount)) as revenue, 4 | c_acctbal, 5 | n_name, 6 | c_address, 7 | c_phone, 8 | c_comment 9 | from 10 | CUSTOMER, 11 | ORDERS, 12 | LINEITEM, 13 | NATION 14 | where 15 | c_custkey = o_custkey 16 | and l_orderkey = o_orderkey 17 | and o_orderdate >= date '1993-08-01' 18 | and o_orderdate < date '1993-08-01' + interval '3' month 19 | and l_returnflag = 'R' 20 | and c_nationkey = n_nationkey 21 | group by 22 | c_custkey, 23 | c_name, 24 | c_acctbal, 25 | c_phone, 26 | n_name, 27 | c_address, 28 | c_comment 29 | order by 30 | revenue desc 31 | limit 20; 32 | -------------------------------------------------------------------------------- /11.sql: -------------------------------------------------------------------------------- 1 | 2 | 3 | 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 = 'MOZAMBIQUE' 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 = 'MOZAMBIQUE') order by value desc; 4 | -------------------------------------------------------------------------------- /12.sql: -------------------------------------------------------------------------------- 1 | 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 ('RAIL', 'FOB') and l_commitdate < l_receiptdate and l_shipdate < l_commitdate and l_receiptdate >= date '1997-01-01' and l_receiptdate < date '1997-01-01' + interval '1' year group by l_shipmode order by l_shipmode; 2 | -------------------------------------------------------------------------------- /13.sql: -------------------------------------------------------------------------------- 1 | select c_count, count(*) as custdist from (select c_custkey, count(o_orderkey) as c_count from CUSTOMER left outer join ORDERS on c_custkey = o_custkey and o_comment not like '%pending%deposits%' group by c_custkey) c_orders group by c_count order by custdist desc, c_count desc; 2 | -------------------------------------------------------------------------------- /14.sql: -------------------------------------------------------------------------------- 1 | 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 >= date '1996-12-01' and l_shipdate < date '1996-12-01' + interval '1' month; 2 | -------------------------------------------------------------------------------- /15.sql: -------------------------------------------------------------------------------- 1 | create view REVENUE0 (supplier_no, total_revenue) as select l_suppkey, sum(l_extendedprice * (1 - l_discount)) from LINEITEM where l_shipdate >= date '1997-07-01' and l_shipdate < date '1997-07-01' + interval '3' month group by l_suppkey; 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; drop view REVENUE0; 2 | -------------------------------------------------------------------------------- /16.sql: -------------------------------------------------------------------------------- 1 | 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#34' and p_type not like 'LARGE BRUSHED%' and p_size in (48, 19, 12, 4, 41, 7, 21, 39) 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; 2 | -------------------------------------------------------------------------------- /17.sql: -------------------------------------------------------------------------------- 1 | select sum(l_extendedprice) / 7.0 as avg_yearly from LINEITEM, PART where p_partkey = l_partkey and p_brand = 'Brand#44' and p_container = 'WRAP PKG' and l_quantity < (select 0.2 * avg(l_quantity) from LINEITEM where l_partkey = p_partkey); 2 | -------------------------------------------------------------------------------- /18.sql: -------------------------------------------------------------------------------- 1 | select 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) > 314) 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 limit 100; 2 | -------------------------------------------------------------------------------- /19.sql: -------------------------------------------------------------------------------- 1 | 2 | select sum(l_extendedprice* (1 - l_discount)) as revenue from LINEITEM, PART where (p_partkey = l_partkey and p_brand = 'Brand#52' and p_container in ('SM CASE', 'SM BOX', 'SM PACK', 'SM PKG') and l_quantity >= 4 and l_quantity <= 4 + 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#11' and p_container in ('MED BAG', 'MED BOX', 'MED PKG', 'MED PACK') and l_quantity >= 18 and l_quantity <= 18 + 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#51' and p_container in ('LG CASE', 'LG BOX', 'LG PACK', 'LG PKG') and l_quantity >= 29 and l_quantity <= 29 + 10 and p_size between 1 and 15 and l_shipmode in ('AIR', 'AIR REG') and l_shipinstruct = 'DELIVER IN PERSON'); 3 | -------------------------------------------------------------------------------- /2.sql: -------------------------------------------------------------------------------- 1 | select s_acctbal, s_name, n_name, p_partkey, p_mfgr, s_address, s_phone, s_comment from PART, SUPPLIER, PARTSUPP, NATION, REGION where p_partkey = ps_partkey and s_suppkey = ps_suppkey and p_size = 30 and p_type like '%STEEL' and s_nationkey = n_nationkey and n_regionkey = r_regionkey and r_name = 'ASIA' and ps_supplycost = (select min(ps_supplycost) from PARTSUPP, SUPPLIER, NATION, REGION where p_partkey = ps_partkey and s_suppkey = ps_suppkey and s_nationkey = n_nationkey and n_regionkey = r_regionkey and r_name = 'ASIA') order by s_acctbal desc, n_name, s_name, p_partkey limit 100; 2 | -------------------------------------------------------------------------------- /20.sql: -------------------------------------------------------------------------------- 1 | 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 'green%') and ps_availqty > (select 0.5 * sum(l_quantity) from LINEITEM where l_partkey = ps_partkey and l_suppkey = ps_suppkey and l_shipdate >= date '1993-01-01' and l_shipdate < date '1993-01-01' + interval '1' year)) and s_nationkey = n_nationkey and n_name = 'ALGERIA' order by s_name; 2 | -------------------------------------------------------------------------------- /21.sql: -------------------------------------------------------------------------------- 1 | select 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 = 'EGYPT' group by s_name order by numwait desc, s_name limit 100; 2 | -------------------------------------------------------------------------------- /22.sql: -------------------------------------------------------------------------------- 1 | select cntrycode, count(*) as numcust, sum(c_acctbal) as totacctbal from (select substring(c_phone from 1 for 2) as cntrycode, c_acctbal from CUSTOMER where substring(c_phone from 1 for 2) in ('20', '40', '22', '30', '39', '42', '21') and c_acctbal > ( select avg(c_acctbal) from CUSTOMER where c_acctbal > 0.00 and substring(c_phone from 1 for 2) in ('20', '40', '22', '30', '39', '42', '21')) and not exists ( select * from ORDERS where o_custkey = c_custkey)) as custsale group by cntrycode order by cntrycode; 2 | -------------------------------------------------------------------------------- /3.sql: -------------------------------------------------------------------------------- 1 | select l_orderkey, sum(l_extendedprice * (1 - l_discount)) as revenue, o_orderdate, o_shippriority from CUSTOMER, ORDERS, LINEITEM where c_mktsegment = 'AUTOMOBILE' and c_custkey = o_custkey and l_orderkey = o_orderkey and o_orderdate < date '1995-03-13' and l_shipdate > date '1995-03-13' group by l_orderkey, o_orderdate, o_shippriority order by revenue desc, o_orderdate limit 10; 2 | -------------------------------------------------------------------------------- /4.sql: -------------------------------------------------------------------------------- 1 | select o_orderpriority, count(*) as order_count from ORDERS where o_orderdate >= date '1995-01-01' and o_orderdate < date '1995-01-01' + interval '3' month and exists (select * from LINEITEM where l_orderkey = o_orderkey and l_commitdate < l_receiptdate) group by o_orderpriority order by o_orderpriority; 2 | -------------------------------------------------------------------------------- /5.sql: -------------------------------------------------------------------------------- 1 | select n_name, sum(l_extendedprice * (1 - l_discount)) as revenue from CUSTOMER, ORDERS, LINEITEM, SUPPLIER, NATION, REGION where c_custkey = o_custkey and l_orderkey = o_orderkey and l_suppkey = s_suppkey and c_nationkey = s_nationkey and s_nationkey = n_nationkey and n_regionkey = r_regionkey and r_name = 'MIDDLE EAST' and o_orderdate >= date '1994-01-01' and o_orderdate < date '1994-01-01' + interval '1' year group by n_name order by revenue desc; 2 | 3 | -------------------------------------------------------------------------------- /6.sql: -------------------------------------------------------------------------------- 1 | 2 | select 3 | sum(l_extendedprice * l_discount) as revenue 4 | from 5 | LINEITEM 6 | where 7 | l_shipdate >= date '1994-01-01' 8 | and l_shipdate < date '1994-01-01' + interval '1' year 9 | and l_discount between 0.06 - 0.01 and 0.06 + 0.01 10 | and l_quantity < 24; 11 | -------------------------------------------------------------------------------- /7.sql: -------------------------------------------------------------------------------- 1 | select supp_nation, cust_nation, l_year, sum(volume) as revenue from ( select n1.n_name as supp_nation, n2.n_name as cust_nation, extract(year from l_shipdate) as l_year, l_extendedprice * (1 - l_discount) as volume from SUPPLIER, LINEITEM, ORDERS, CUSTOMER, NATION n1, NATION n2 where s_suppkey = l_suppkey and o_orderkey = l_orderkey and c_custkey = o_custkey and s_nationkey = n1.n_nationkey and c_nationkey = n2.n_nationkey and ((n1.n_name = 'JAPAN' and n2.n_name = 'INDIA') or (n1.n_name = 'INDIA' and n2.n_name = 'JAPAN')) and l_shipdate between date '1995-01-01' and date '1996-12-31') as shipping group by supp_nation, cust_nation, l_year order by supp_nation, cust_nation, l_year; 2 | -------------------------------------------------------------------------------- /8.sql: -------------------------------------------------------------------------------- 1 | select o_year, sum(case when nation = 'INDIA' then volume else 0 end) / sum(volume) as mkt_share from (select extract(year from o_orderdate) as o_year, l_extendedprice * (1 - l_discount) as volume, n2.n_name as nation from PART, SUPPLIER, LINEITEM, ORDERS, CUSTOMER, NATION n1, NATION n2, REGION where p_partkey = l_partkey and s_suppkey = l_suppkey and l_orderkey = o_orderkey and o_custkey = c_custkey and c_nationkey = n1.n_nationkey and n1.n_regionkey = r_regionkey and r_name = 'ASIA' and s_nationkey = n2.n_nationkey and o_orderdate between date '1995-01-01' and date '1996-12-31'and p_type = 'SMALL PLATED COPPER') as all_nations group by o_year order by o_year; 2 | -------------------------------------------------------------------------------- /9.sql: -------------------------------------------------------------------------------- 1 | select nation, o_year, sum(amount) as sum_profit from (select n_name as nation, extract(year from o_orderdate) as o_year, l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity as amount from PART, SUPPLIER, LINEITEM, PARTSUPP, ORDERS, NATION where s_suppkey = l_suppkey and ps_suppkey = l_suppkey and ps_partkey = l_partkey and p_partkey = l_partkey and o_orderkey = l_orderkey and s_nationkey = n_nationkey and p_name like '%dim%') as profit group by nation, o_year order by nation, o_year desc; 2 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # queries-tpch-dbgen-mysql 2 | TPC-H Benchmark, specific for MYSQL 3 | 4 | Implementation TPC-H schema into MySQL DBMS: TUTORIAL 5 | 6 | [Download the DBGEN and reference data](http://www.tpc.org/tpch/spec/tpch_2_16_0.zip) 7 | Unzip the downloaded file 8 | Navigate through the command line to DBGEN folder 9 | ``` 10 | $ cd Downloads/tpch_2_16_0/tpch_2_15_0/dbgen/ 11 | ``` 12 | 13 | Make a copy of the dummy makefile 14 | ``` 15 | $ cp makefile.suite makefile 16 | ``` 17 | 18 | In dbgen folder find the created makefile and insert highlighted values (bold) to this file. 19 | ``` 20 | ################ 21 | ## CHANGE NAME OF ANSI COMPILER HERE 22 | ################ 23 | CC = gcc 24 | # Current values for DATABASE are: INFORMIX, DB2, TDAT (Teradata) 25 | # SQLSERVER, SYBASE, ORACLE, VECTORWISE 26 | # Current values for MACHINE are: ATT, DOS, HP, IBM, ICL, MVS, 27 | # SGI, SUN, U2200, VMS, LINUX, WIN32 28 | # Current values for WORKLOAD are: TPCH 29 | DATABASE= *QLSERVER* 30 | MACHINE = *LINUX* 31 | WORKLOAD = *TPCH* 32 | # 33 | ... 34 | ``` 35 | 36 | In dbgen folder find the *tpcd.h* file and edit higlighted (bold) values for SQLSERVER. 37 | ``` 38 | ... 39 | #ifdef SQLSERVER 40 | #define GEN_QUERY_PLAN "set showplan on\nset noexec on\ngo\n" 41 | #define START_TRAN "**BEGIN WORK;**" 42 | #define END_TRAN "**COMMIT WORK;**" 43 | #define SET_OUTPUT "" 44 | #define SET_ROWCOUNT "limit %d;\n\n" 45 | #define SET_DBASE "use %s;\n" 46 | #endif 47 | ... 48 | ``` 49 | 50 | Run make command. 51 | ``` 52 | $ make 53 | ``` 54 | 55 | Generate the files for population. (The last numeric parametr determines the volume of data with which will be your database then populated - I decided that 0.1 (=100MB) is fine for my purposes, since I am not interested in the database benchmark tests. 56 | ``` 57 | $ ./dbgen -s 0.1 58 | ``` 59 | 60 | Connect to SQL server with permission to reach local files, create database and connect to schema. 61 | ``` 62 | $ mysql -u root -p --local-infile 63 | $ mysql> CREATE DATABASE tpch; 64 | $ mysql> USE tpch; 65 | ``` 66 | 67 | Run following queries in SQL console uploaded in this repository. 68 | ``` 69 | CREATE TABLE NATION ( N_NATIONKEY INTEGER NOT NULL, 70 | N_NAME CHAR(25) NOT NULL, 71 | N_REGIONKEY INTEGER NOT NULL, 72 | N_COMMENT VARCHAR(152)); 73 | 74 | CREATE TABLE REGION ( R_REGIONKEY INTEGER NOT NULL, 75 | R_NAME CHAR(25) NOT NULL, 76 | R_COMMENT VARCHAR(152)); 77 | 78 | CREATE TABLE PART ( P_PARTKEY INTEGER NOT NULL, 79 | P_NAME VARCHAR(55) NOT NULL, 80 | P_MFGR CHAR(25) NOT NULL, 81 | P_BRAND CHAR(10) NOT NULL, 82 | P_TYPE VARCHAR(25) NOT NULL, 83 | P_SIZE INTEGER NOT NULL, 84 | P_CONTAINER CHAR(10) NOT NULL, 85 | P_RETAILPRICE DECIMAL(15,2) NOT NULL, 86 | P_COMMENT VARCHAR(23) NOT NULL ); 87 | 88 | CREATE TABLE SUPPLIER ( S_SUPPKEY INTEGER NOT NULL, 89 | S_NAME CHAR(25) NOT NULL, 90 | S_ADDRESS VARCHAR(40) NOT NULL, 91 | S_NATIONKEY INTEGER NOT NULL, 92 | S_PHONE CHAR(15) NOT NULL, 93 | S_ACCTBAL DECIMAL(15,2) NOT NULL, 94 | S_COMMENT VARCHAR(101) NOT NULL); 95 | 96 | CREATE TABLE PARTSUPP ( PS_PARTKEY INTEGER NOT NULL, 97 | PS_SUPPKEY INTEGER NOT NULL, 98 | PS_AVAILQTY INTEGER NOT NULL, 99 | PS_SUPPLYCOST DECIMAL(15,2) NOT NULL, 100 | PS_COMMENT VARCHAR(199) NOT NULL ); 101 | 102 | CREATE TABLE CUSTOMER ( C_CUSTKEY INTEGER NOT NULL, 103 | C_NAME VARCHAR(25) NOT NULL, 104 | C_ADDRESS VARCHAR(40) NOT NULL, 105 | C_NATIONKEY INTEGER NOT NULL, 106 | C_PHONE CHAR(15) NOT NULL, 107 | C_ACCTBAL DECIMAL(15,2) NOT NULL, 108 | C_MKTSEGMENT CHAR(10) NOT NULL, 109 | C_COMMENT VARCHAR(117) NOT NULL); 110 | 111 | CREATE TABLE ORDERS ( O_ORDERKEY INTEGER NOT NULL, 112 | O_CUSTKEY INTEGER NOT NULL, 113 | O_ORDERSTATUS CHAR(1) NOT NULL, 114 | O_TOTALPRICE DECIMAL(15,2) NOT NULL, 115 | O_ORDERDATE DATE NOT NULL, 116 | O_ORDERPRIORITY CHAR(15) NOT NULL, 117 | O_CLERK CHAR(15) NOT NULL, 118 | O_SHIPPRIORITY INTEGER NOT NULL, 119 | O_COMMENT VARCHAR(79) NOT NULL); 120 | 121 | CREATE TABLE LINEITEM ( L_ORDERKEY INTEGER NOT NULL, 122 | L_PARTKEY INTEGER NOT NULL, 123 | L_SUPPKEY INTEGER NOT NULL, 124 | L_LINENUMBER INTEGER NOT NULL, 125 | L_QUANTITY DECIMAL(15,2) NOT NULL, 126 | L_EXTENDEDPRICE DECIMAL(15,2) NOT NULL, 127 | L_DISCOUNT DECIMAL(15,2) NOT NULL, 128 | L_TAX DECIMAL(15,2) NOT NULL, 129 | L_RETURNFLAG CHAR(1) NOT NULL, 130 | L_LINESTATUS CHAR(1) NOT NULL, 131 | L_SHIPDATE DATE NOT NULL, 132 | L_COMMITDATE DATE NOT NULL, 133 | L_RECEIPTDATE DATE NOT NULL, 134 | L_SHIPINSTRUCT CHAR(25) NOT NULL, 135 | L_SHIPMODE CHAR(10) NOT NULL, 136 | L_COMMENT VARCHAR(44) NOT NULL); 137 | ``` 138 | 139 | Populate tables with generated dummy data. 140 | ``` 141 | LOAD DATA LOCAL INFILE 'customer.tbl' INTO TABLE CUSTOMER FIELDS TERMINATED BY '|'; 142 | LOAD DATA LOCAL INFILE 'orders.tbl' INTO TABLE ORDERS FIELDS TERMINATED BY '|'; 143 | LOAD DATA LOCAL INFILE 'lineitem.tbl' INTO TABLE LINEITEM FIELDS TERMINATED BY '|'; 144 | LOAD DATA LOCAL INFILE 'nation.tbl' INTO TABLE NATION FIELDS TERMINATED BY '|'; 145 | LOAD DATA LOCAL INFILE 'partsupp.tbl' INTO TABLE PARTSUPP FIELDS TERMINATED BY '|'; 146 | LOAD DATA LOCAL INFILE 'part.tbl' INTO TABLE PART FIELDS TERMINATED BY '|'; 147 | LOAD DATA LOCAL INFILE 'region.tbl' INTO TABLE REGION FIELDS TERMINATED BY '|'; 148 | LOAD DATA LOCAL INFILE 'supplier.tbl' INTO TABLE SUPPLIER FIELDS TERMINATED BY '|'; 149 | ``` 150 | 151 | Alter the schema dependencies (The original statement can be found in dss.ri. This is my modified version in order to work with MySQL.) 152 | 153 | ``` 154 | ALTER TABLE REGION 155 | ADD PRIMARY KEY (R_REGIONKEY); 156 | ALTER TABLE NATION 157 | ADD PRIMARY KEY (N_NATIONKEY); 158 | ALTER TABLE NATION 159 | ADD FOREIGN KEY NATION_FK1 (N_REGIONKEY) references REGION(R_REGIONKEY); 160 | ALTER TABLE PART 161 | ADD PRIMARY KEY (P_PARTKEY); 162 | ALTER TABLE SUPPLIER 163 | ADD PRIMARY KEY (S_SUPPKEY); 164 | ALTER TABLE SUPPLIER 165 | ADD FOREIGN KEY SUPPLIER_FK1 (S_NATIONKEY) references NATION(N_NATIONKEY); 166 | ALTER TABLE PARTSUPP 167 | ADD PRIMARY KEY (PS_PARTKEY,PS_SUPPKEY); 168 | ALTER TABLE CUSTOMER 169 | ADD PRIMARY KEY (C_CUSTKEY); 170 | ALTER TABLE CUSTOMER 171 | ADD FOREIGN KEY CUSTOMER_FK1 (C_NATIONKEY) references NATION(N_NATIONKEY); 172 | ALTER TABLE LINEITEM 173 | ADD PRIMARY KEY (L_ORDERKEY,L_LINENUMBER); 174 | ALTER TABLE PARTSUPP 175 | ADD FOREIGN KEY PARTSUPP_FK1 (PS_SUPPKEY) references SUPPLIER(S_SUPPKEY); 176 | ALTER TABLE PARTSUPP 177 | ADD FOREIGN KEY PARTSUPP_FK2 (PS_PARTKEY) references PART(P_PARTKEY); 178 | ALTER TABLE ORDERS 179 | ADD FOREIGN KEY ORDERS_FK1 (O_CUSTKEY) references CUSTOMER(C_CUSTKEY); 180 | ALTER TABLE LINEITEM 181 | ADD FOREIGN KEY LINEITEM_FK1 (L_ORDERKEY) references ORDERS(O_ORDERKEY); 182 | ALTER TABLE LINEITEM 183 | ADD FOREIGN KEY LINEITEM_FK2 (L_PARTKEY,L_SUPPKEY) references PARTSUPP(PS_PARTKEY, PS_SUPPKEY); 184 | ``` 185 | 186 | Now you can run your test the queries uploaded in this repository. 187 | Hope that's useful! 188 | --------------------------------------------------------------------------------