From f8c8c03f5253e1cb1e72fd744c00f97c6dcb0e92 Mon Sep 17 00:00:00 2001 From: Kuien Liu Date: Wed, 18 Jul 2018 16:39:39 +0800 Subject: [PATCH] Add SQL files of ddl and queries qgen does not work because query templates are missing. --- queries/DDL.sql | 62 ++++++++++++++++++++++++++++++++++++++++++++++++ queries/Q1.1.sql | 7 ++++++ queries/Q1.2.sql | 7 ++++++ queries/Q1.3.sql | 8 +++++++ queries/Q2.1.sql | 10 ++++++++ queries/Q2.2.sql | 11 +++++++++ queries/Q2.3.sql | 10 ++++++++ queries/Q3.1.sql | 12 ++++++++++ queries/Q3.2.sql | 11 +++++++++ queries/Q3.3.sql | 11 +++++++++ queries/Q3.4.sql | 14 +++++++++++ queries/Q4.1.sql | 13 ++++++++++ queries/Q4.2.sql | 14 +++++++++++ queries/Q4.3.sql | 13 ++++++++++ 14 files changed, 203 insertions(+) create mode 100644 queries/DDL.sql create mode 100644 queries/Q1.1.sql create mode 100644 queries/Q1.2.sql create mode 100644 queries/Q1.3.sql create mode 100644 queries/Q2.1.sql create mode 100644 queries/Q2.2.sql create mode 100644 queries/Q2.3.sql create mode 100644 queries/Q3.1.sql create mode 100644 queries/Q3.2.sql create mode 100644 queries/Q3.3.sql create mode 100644 queries/Q3.4.sql create mode 100644 queries/Q4.1.sql create mode 100644 queries/Q4.2.sql create mode 100644 queries/Q4.3.sql diff --git a/queries/DDL.sql b/queries/DDL.sql new file mode 100644 index 0000000..7fa2337 --- /dev/null +++ b/queries/DDL.sql @@ -0,0 +1,62 @@ +CREATE TABLE CUSTOMER ( C_CUSTKEY INTEGER, + C_NAME VARCHAR(25) NOT NULL, + C_ADDRESS VARCHAR(40) NOT NULL, + C_CITY VARCHAR(10) NOT NULL, + C_NATION VARCHAR(15) NOT NULL, + C_REGION VARCHAR(12) NOT NULL, + C_PHONE VARCHAR(15) NOT NULL, + C_MKTSEGMENT VARCHAR(10) NOT NULL); + +CREATE TABLE DATES ( D_DATEKEY INTEGER, + D_DATE VARCHAR(18) NOT NULL, + D_DAYOFWEEK VARCHAR(18) NOT NULL, + D_MONTH VARCHAR(9) NOT NULL, + D_YEAR INTEGER NOT NULL, + D_YEARMONTHNUM INTEGER, + D_YEARMONTH VARCHAR(7) NOT NULL, + D_DAYNUMINWEEK INTEGER, + D_DAYNUMINMONTH INTEGER, + D_DAYNUMINYEAR INTEGER, + D_MONTHNUMINYEAR INTEGER, + D_WEEKNUMINYEAR INTEGER, + D_SELLINGSEASON VARCHAR(12) NOT NULL, + D_LASTDAYINWEEKFL INTEGER, + D_LASTDAYINMONTHFL INTEGER, + D_HOLIDAYFL INTEGER, + D_WEEKDAYFL INTEGER); + +CREATE TABLE PART ( P_PARTKEY INTEGER, + P_NAME VARCHAR(22) NOT NULL, + P_MFGR VARCHAR(6) NOT NULL, + P_CATEGORY VARCHAR(7) NOT NULL, + P_BRAND VARCHAR(9) NOT NULL, + P_COLOR VARCHAR(11) NOT NULL, + P_TYPE VARCHAR(25) NOT NULL, + P_SIZE INTEGER NOT NULL, + P_CONTAINER VARCHAR(10) NOT NULL); + +CREATE TABLE SUPPLIER ( S_SUPPKEY INTEGER, + S_NAME VARCHAR(25) NOT NULL, + S_ADDRESS VARCHAR(25) NOT NULL, + S_CITY VARCHAR(10) NOT NULL, + S_NATION VARCHAR(15) NOT NULL, + S_REGION VARCHAR(12) NOT NULL, + S_PHONE VARCHAR(15) NOT NULL); + +CREATE TABLE LINEORDER ( LO_ORDERKEY BIGINT, + LO_LINENUMBER BIGINT, + LO_CUSTKEY INTEGER NOT NULL, + LO_PARTKEY INTEGER NOT NULL, + LO_SUPPKEY INTEGER NOT NULL, + LO_ORDERDATE INTEGER NOT NULL, + LO_ORDERPRIOTITY VARCHAR(15) NOT NULL, + LO_SHIPPRIOTITY INTEGER, + LO_QUANTITY BIGINT, + LO_EXTENDEDPRICE BIGINT, + LO_ORDTOTALPRICE BIGINT, + LO_DISCOUNT BIGINT, + LO_REVENUE BIGINT, + LO_SUPPLYCOST BIGINT, + LO_TAX BIGINT, + LO_COMMITDATE INTEGER NOT NULL, + LO_SHIPMODE VARCHAR(10) NOT NULL); diff --git a/queries/Q1.1.sql b/queries/Q1.1.sql new file mode 100644 index 0000000..3464c1d --- /dev/null +++ b/queries/Q1.1.sql @@ -0,0 +1,7 @@ +--PROMPT Q1.1 +SELECT SUM(LO_EXTENDEDPRICE*LO_DISCOUNT) AS REVENUE +FROM LINEORDER, DATES +WHERE LO_ORDERDATE = D_DATEKEY + AND D_YEAR = 1993 + AND LO_DISCOUNT BETWEEN 1 AND 3 + AND LO_QUANTITY < 25; diff --git a/queries/Q1.2.sql b/queries/Q1.2.sql new file mode 100644 index 0000000..8792448 --- /dev/null +++ b/queries/Q1.2.sql @@ -0,0 +1,7 @@ +-- PROMPT Q1.2 +SELECT SUM(LO_EXTENDEDPRICE*LO_DISCOUNT) AS REVENUE +FROM LINEORDER, DATES +WHERE LO_ORDERDATE = D_DATEKEY + AND D_YEARMONTH = 'Jan1994' + AND LO_DISCOUNT BETWEEN 4 AND 6 + AND LO_QUANTITY BETWEEN 26 AND 35; diff --git a/queries/Q1.3.sql b/queries/Q1.3.sql new file mode 100644 index 0000000..f1434ad --- /dev/null +++ b/queries/Q1.3.sql @@ -0,0 +1,8 @@ +--PROMPT Q1.3 +SELECT SUM(LO_EXTENDEDPRICE*LO_DISCOUNT) AS REVENUE +FROM LINEORDER, DATES +WHERE LO_ORDERDATE = D_DATEKEY + AND D_WEEKNUMINYEAR = 6 + AND D_YEAR = 1994 + AND LO_DISCOUNT BETWEEN 5 AND 7 + AND LO_QUANTITY BETWEEN 26 AND 35; diff --git a/queries/Q2.1.sql b/queries/Q2.1.sql new file mode 100644 index 0000000..70e04db --- /dev/null +++ b/queries/Q2.1.sql @@ -0,0 +1,10 @@ +--PROMPT Q2.1 +SELECT SUM(LO_REVENUE), D_YEAR, P_BRAND +FROM LINEORDER, DATES, PART, SUPPLIER +WHERE LO_ORDERDATE = D_DATEKEY + AND LO_PARTKEY = P_PARTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND P_CATEGORY = 'MFGR#12' + AND S_REGION = 'AMERICA' +GROUP BY D_YEAR, P_BRAND +ORDER BY D_YEAR, P_BRAND; diff --git a/queries/Q2.2.sql b/queries/Q2.2.sql new file mode 100644 index 0000000..ddc76b4 --- /dev/null +++ b/queries/Q2.2.sql @@ -0,0 +1,11 @@ +--PROMPT Q2.2 +SELECT SUM(LO_REVENUE), D_YEAR, P_BRAND +FROM LINEORDER, DATES, PART, SUPPLIER +WHERE LO_ORDERDATE = D_DATEKEY + AND LO_PARTKEY = P_PARTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND P_BRAND BETWEEN 'MFGR#2221' + AND 'MFGR#2228' + AND S_REGION = 'ASIA' +GROUP BY D_YEAR, P_BRAND +ORDER BY D_YEAR, P_BRAND; diff --git a/queries/Q2.3.sql b/queries/Q2.3.sql new file mode 100644 index 0000000..bf0c053 --- /dev/null +++ b/queries/Q2.3.sql @@ -0,0 +1,10 @@ +--PROMPT Q2.3 +SELECT SUM(LO_REVENUE), D_YEAR, P_BRAND +FROM LINEORDER, DATES, PART, SUPPLIER +WHERE LO_ORDERDATE = D_DATEKEY + AND LO_PARTKEY = P_PARTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND P_BRAND= 'MFGR#2239' + AND S_REGION = 'EUROPE' +GROUP BY D_YEAR, P_BRAND +ORDER BY D_YEAR, P_BRAND; diff --git a/queries/Q3.1.sql b/queries/Q3.1.sql new file mode 100644 index 0000000..85bbfad --- /dev/null +++ b/queries/Q3.1.sql @@ -0,0 +1,12 @@ +--PROMPT Q3.1 +SELECT C_NATION, S_NATION, D_YEAR, + SUM(LO_REVENUE) AS REVENUE +FROM CUSTOMER, LINEORDER, SUPPLIER, DATES +WHERE LO_CUSTKEY = C_CUSTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND LO_ORDERDATE = D_DATEKEY + AND C_REGION = 'ASIA' + AND S_REGION = 'ASIA' + AND D_YEAR >= 1992 AND D_YEAR <= 1997 +GROUP BY C_NATION, S_NATION, D_YEAR +ORDER BY D_YEAR ASC, REVENUE DESC; diff --git a/queries/Q3.2.sql b/queries/Q3.2.sql new file mode 100644 index 0000000..95a7998 --- /dev/null +++ b/queries/Q3.2.sql @@ -0,0 +1,11 @@ +--PROMPT Q3.2 +SELECT C_CITY, S_CITY, D_YEAR, SUM(LO_REVENUE) AS REVENUE +FROM CUSTOMER, LINEORDER, SUPPLIER, DATES +WHERE LO_CUSTKEY = C_CUSTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND LO_ORDERDATE = D_DATEKEY + AND C_NATION = 'UNITED STATES' + AND S_NATION = 'UNITED STATES' + AND D_YEAR >= 1992 AND D_YEAR <= 1997 +GROUP BY C_CITY, S_CITY, D_YEAR +ORDER BY D_YEAR ASC, REVENUE DESC; diff --git a/queries/Q3.3.sql b/queries/Q3.3.sql new file mode 100644 index 0000000..4ce917f --- /dev/null +++ b/queries/Q3.3.sql @@ -0,0 +1,11 @@ +--PROMPT Q3.3 +SELECT C_CITY, S_CITY, D_YEAR, SUM(LO_REVENUE) AS REVENUE +FROM CUSTOMER, LINEORDER, SUPPLIER, DATES +WHERE LO_CUSTKEY = C_CUSTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND LO_ORDERDATE = D_DATEKEY + AND (C_CITY='UNITED KI1' OR C_CITY='UNITED KI5') + AND (S_CITY='UNITED KI1' OR S_CITY='UNITED KI5') + AND D_YEAR >= 1992 AND D_YEAR <= 1997 +GROUP BY C_CITY, S_CITY, D_YEAR +ORDER BY D_YEAR ASC, REVENUE DESC; diff --git a/queries/Q3.4.sql b/queries/Q3.4.sql new file mode 100644 index 0000000..9dc1f24 --- /dev/null +++ b/queries/Q3.4.sql @@ -0,0 +1,14 @@ +--PROMPT Q3.4 +SELECT C_CITY, S_CITY, D_YEAR, SUM(LO_REVENUE) +AS REVENUE +FROM CUSTOMER, LINEORDER, SUPPLIER, DATES +WHERE LO_CUSTKEY = C_CUSTKEY +AND LO_SUPPKEY = S_SUPPKEY +AND LO_ORDERDATE = D_DATEKEY +AND (C_CITY='UNITED KI1' +OR C_CITY='UNITED KI5') +AND (S_CITY='UNITED KI1' +OR S_CITY='UNITED KI5') +AND D_YEARMONTH = 'Dec1997' +GROUP BY C_CITY, S_CITY, D_YEAR +ORDER BY D_YEAR ASC, REVENUE DESC; diff --git a/queries/Q4.1.sql b/queries/Q4.1.sql new file mode 100644 index 0000000..77041d9 --- /dev/null +++ b/queries/Q4.1.sql @@ -0,0 +1,13 @@ +--PROMPT Q4.1 +SELECT D_YEAR, C_NATION, + SUM(LO_REVENUE - LO_SUPPLYCOST) AS PROFIT +FROM DATES, CUSTOMER, SUPPLIER, PART, LINEORDER +WHERE LO_CUSTKEY = C_CUSTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND LO_PARTKEY = P_PARTKEY + AND LO_ORDERDATE = D_DATEKEY + AND C_REGION = 'AMERICA' + AND S_REGION = 'AMERICA' + AND (P_MFGR = 'MFGR#1' OR P_MFGR = 'MFGR#2') +GROUP BY D_YEAR, C_NATION +ORDER BY D_YEAR, C_NATION; diff --git a/queries/Q4.2.sql b/queries/Q4.2.sql new file mode 100644 index 0000000..f155a38 --- /dev/null +++ b/queries/Q4.2.sql @@ -0,0 +1,14 @@ +--PROMPT Q4.2 +SELECT D_YEAR, S_NATION, P_CATEGORY, + SUM(LO_REVENUE - LO_SUPPLYCOST) AS PROFIT +FROM DATES, CUSTOMER, SUPPLIER, PART, LINEORDER +WHERE LO_CUSTKEY = C_CUSTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND LO_PARTKEY = P_PARTKEY + AND LO_ORDERDATE = D_DATEKEY + AND C_REGION = 'AMERICA' + AND S_REGION = 'AMERICA' + AND (D_YEAR = 1997 OR D_YEAR = 1998) + AND (P_MFGR = 'MFGR#1' OR P_MFGR = 'MFGR#2') +GROUP BY D_YEAR, S_NATION, P_CATEGORY +ORDER BY D_YEAR, S_NATION, P_CATEGORY; diff --git a/queries/Q4.3.sql b/queries/Q4.3.sql new file mode 100644 index 0000000..fc85852 --- /dev/null +++ b/queries/Q4.3.sql @@ -0,0 +1,13 @@ +--PROMPT Q4.3 +SELECT D_YEAR, S_CITY, P_BRAND, + SUM(LO_REVENUE - LO_SUPPLYCOST) AS PROFIT +FROM DATES, CUSTOMER, SUPPLIER, PART, LINEORDER +WHERE LO_CUSTKEY = C_CUSTKEY + AND LO_SUPPKEY = S_SUPPKEY + AND LO_PARTKEY = P_PARTKEY + AND LO_ORDERDATE = D_DATEKEY + AND S_NATION = 'UNITED STATES' + AND (D_YEAR = 1997 OR D_YEAR = 1998) + AND P_CATEGORY = 'MFGR#14' +GROUP BY D_YEAR, S_CITY, P_BRAND +ORDER BY D_YEAR, S_CITY, P_BRAND;