From e6d8d07f76c06f7baef8806711208a002ce34eb7 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Hannes=20M=C3=BChleisen?= <hannes@muehleisen.org> Date: Sun, 6 Apr 2014 15:23:55 +0200 Subject: [PATCH] added mariadb scripts, not finished yet --- queries/q17.sql | 17 ++++++++ queries/q20.sql | 37 +++++++++++++++++ scripts/mariadb.analyze.sql | 8 ++++ scripts/mariadb.constraints.sql | 44 ++++++++++++++++++++ scripts/mariadb.load.sql | 8 ++++ scripts/mariadb.schema.sql | 72 +++++++++++++++++++++++++++++++++ 6 files changed, 186 insertions(+) create mode 100644 queries/q17.sql create mode 100644 queries/q20.sql create mode 100644 scripts/mariadb.analyze.sql create mode 100644 scripts/mariadb.constraints.sql create mode 100644 scripts/mariadb.load.sql create mode 100644 scripts/mariadb.schema.sql diff --git a/queries/q17.sql b/queries/q17.sql new file mode 100644 index 0000000..c7943f5 --- /dev/null +++ b/queries/q17.sql @@ -0,0 +1,17 @@ +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 + ); diff --git a/queries/q20.sql b/queries/q20.sql new file mode 100644 index 0000000..f81ae27 --- /dev/null +++ b/queries/q20.sql @@ -0,0 +1,37 @@ +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 >= date '1994-01-01' + and l_shipdate < date '1994-01-01' + interval '1' year + ) + ) + and s_nationkey = n_nationkey + and n_name = 'CANADA' +order by + s_name; diff --git a/scripts/mariadb.analyze.sql b/scripts/mariadb.analyze.sql new file mode 100644 index 0000000..9009be7 --- /dev/null +++ b/scripts/mariadb.analyze.sql @@ -0,0 +1,8 @@ +analyze table customer; +analyze table lineitem; +analyze table nation; +analyze table orders; +analyze table part; +analyze table partsupp; +analyze table region; +analyze table supplier; diff --git a/scripts/mariadb.constraints.sql b/scripts/mariadb.constraints.sql new file mode 100644 index 0000000..1abb54f --- /dev/null +++ b/scripts/mariadb.constraints.sql @@ -0,0 +1,44 @@ +-- TPCH integry constraints for postgres 9.x +-- hannes@cwi.nl, 2014-04-04 + +-- For table REGION +ALTER TABLE REGION ADD PRIMARY KEY (R_REGIONKEY); + +-- For table NATION +ALTER TABLE NATION ADD PRIMARY KEY (N_NATIONKEY); +ALTER TABLE NATION ADD CONSTRAINT NATION_FK1 FOREIGN KEY (N_REGIONKEY) REFERENCES REGION; + +-- For table PART +ALTER TABLE PART ADD PRIMARY KEY (P_PARTKEY); + +-- For table SUPPLIER +ALTER TABLE SUPPLIER ADD PRIMARY KEY (S_SUPPKEY); +ALTER TABLE SUPPLIER ADD CONSTRAINT SUPPLIER_FK1 FOREIGN KEY (S_NATIONKEY) REFERENCES NATION; + +-- For table PARTSUPP +ALTER TABLE PARTSUPP ADD PRIMARY KEY (PS_PARTKEY,PS_SUPPKEY); + +-- For table CUSTOMER +ALTER TABLE CUSTOMER ADD PRIMARY KEY (C_CUSTKEY); +ALTER TABLE CUSTOMER ADD CONSTRAINT CUSTOMER_FK1 FOREIGN KEY (C_NATIONKEY) REFERENCES NATION; + +-- For table LINEITEM +ALTER TABLE LINEITEM ADD PRIMARY KEY (L_ORDERKEY,L_LINENUMBER); + +-- For table ORDERS +ALTER TABLE ORDERS ADD PRIMARY KEY (O_ORDERKEY); + +-- For table PARTSUPP +ALTER TABLE PARTSUPP ADD CONSTRAINT PARTSUPP_FK1 FOREIGN KEY (PS_SUPPKEY) REFERENCES SUPPLIER; +ALTER TABLE PARTSUPP ADD CONSTRAINT PARTSUPP_FK2 FOREIGN KEY (PS_PARTKEY) REFERENCES PART; + +-- For table ORDERS +ALTER TABLE ORDERS ADD CONSTRAINT ORDERS_FK1 FOREIGN KEY (O_CUSTKEY) REFERENCES CUSTOMER; + +-- For table LINEITEM +ALTER TABLE LINEITEM ADD CONSTRAINT LINEITEM_FK1 FOREIGN KEY (L_ORDERKEY) REFERENCES ORDERS; +ALTER TABLE LINEITEM ADD CONSTRAINT LINEITEM_FK2 FOREIGN KEY (L_PARTKEY,L_SUPPKEY) REFERENCES PARTSUPP; + + + + diff --git a/scripts/mariadb.load.sql b/scripts/mariadb.load.sql new file mode 100644 index 0000000..a2105d6 --- /dev/null +++ b/scripts/mariadb.load.sql @@ -0,0 +1,8 @@ +COPY customer FROM 'DIR/customer.tbl' WITH DELIMITER AS '|'; +COPY lineitem FROM 'DIR/lineitem.tbl' WITH DELIMITER AS '|'; +COPY nation FROM 'DIR/nation.tbl' WITH DELIMITER AS '|'; +COPY orders FROM 'DIR/orders.tbl' WITH DELIMITER AS '|'; +COPY part FROM 'DIR/part.tbl' WITH DELIMITER AS '|'; +COPY partsupp FROM 'DIR/partsupp.tbl' WITH DELIMITER AS '|'; +COPY region FROM 'DIR/region.tbl' WITH DELIMITER AS '|'; +COPY supplier FROM 'DIR/supplier.tbl' WITH DELIMITER AS '|'; diff --git a/scripts/mariadb.schema.sql b/scripts/mariadb.schema.sql new file mode 100644 index 0000000..aed682a --- /dev/null +++ b/scripts/mariadb.schema.sql @@ -0,0 +1,72 @@ +-- TPCH schema postgres 9.x +-- hannes@cwi.nl, 2014-04-04 + +CREATE TABLE NATION ( N_NATIONKEY INTEGER NOT NULL, + N_NAME CHAR(25) NOT NULL, + N_REGIONKEY INTEGER NOT NULL, + N_COMMENT VARCHAR(152)); + +CREATE TABLE REGION ( R_REGIONKEY INTEGER NOT NULL, + R_NAME CHAR(25) NOT NULL, + R_COMMENT VARCHAR(152)); + +CREATE TABLE PART ( P_PARTKEY INTEGER NOT NULL, + P_NAME VARCHAR(55) NOT NULL, + P_MFGR CHAR(25) NOT NULL, + P_BRAND CHAR(10) NOT NULL, + P_TYPE VARCHAR(25) NOT NULL, + P_SIZE INTEGER NOT NULL, + P_CONTAINER CHAR(10) NOT NULL, + P_RETAILPRICE DECIMAL(15,2) NOT NULL, + P_COMMENT VARCHAR(23) NOT NULL ); + +CREATE TABLE SUPPLIER ( S_SUPPKEY INTEGER NOT NULL, + S_NAME CHAR(25) NOT NULL, + S_ADDRESS VARCHAR(40) NOT NULL, + S_NATIONKEY INTEGER NOT NULL, + S_PHONE CHAR(15) NOT NULL, + S_ACCTBAL DECIMAL(15,2) NOT NULL, + S_COMMENT VARCHAR(101) NOT NULL); + +CREATE TABLE PARTSUPP ( PS_PARTKEY INTEGER NOT NULL, + PS_SUPPKEY INTEGER NOT NULL, + PS_AVAILQTY INTEGER NOT NULL, + PS_SUPPLYCOST DECIMAL(15,2) NOT NULL, + PS_COMMENT VARCHAR(199) NOT NULL ); + +CREATE TABLE CUSTOMER ( C_CUSTKEY INTEGER NOT NULL, + C_NAME VARCHAR(25) NOT NULL, + C_ADDRESS VARCHAR(40) NOT NULL, + C_NATIONKEY INTEGER NOT NULL, + C_PHONE CHAR(15) NOT NULL, + C_ACCTBAL DECIMAL(15,2) NOT NULL, + C_MKTSEGMENT CHAR(10) NOT NULL, + C_COMMENT VARCHAR(117) NOT NULL); + +CREATE TABLE ORDERS ( O_ORDERKEY INTEGER NOT NULL, + O_CUSTKEY INTEGER NOT NULL, + O_ORDERSTATUS CHAR(1) NOT NULL, + O_TOTALPRICE DECIMAL(15,2) NOT NULL, + O_ORDERDATE DATE NOT NULL, + O_ORDERPRIORITY CHAR(15) NOT NULL, + O_CLERK CHAR(15) NOT NULL, + O_SHIPPRIORITY INTEGER NOT NULL, + O_COMMENT VARCHAR(79) NOT NULL); + +CREATE TABLE LINEITEM ( L_ORDERKEY INTEGER NOT NULL, + L_PARTKEY INTEGER NOT NULL, + L_SUPPKEY INTEGER NOT NULL, + L_LINENUMBER INTEGER NOT NULL, + L_QUANTITY DECIMAL(15,2) NOT NULL, + L_EXTENDEDPRICE DECIMAL(15,2) NOT NULL, + L_DISCOUNT DECIMAL(15,2) NOT NULL, + L_TAX DECIMAL(15,2) NOT NULL, + L_RETURNFLAG CHAR(1) NOT NULL, + L_LINESTATUS CHAR(1) NOT NULL, + L_SHIPDATE DATE NOT NULL, + L_COMMITDATE DATE NOT NULL, + L_RECEIPTDATE DATE NOT NULL, + L_SHIPINSTRUCT CHAR(25) NOT NULL, + L_SHIPMODE CHAR(10) NOT NULL, + L_COMMENT VARCHAR(44) NOT NULL); + -- GitLab