The TPCH bentchmark provides up to twenty-two decision support queries that must be executed as part of the TPC-H benchmark.

Each TPC-H query asks a business question and includes the corresponding query to answer the question.

1 Q1 - Pricing Summary Report Query

This query reports the amount of business that was billed, shipped, and returned.

1.1 Business Question

The Pricing Summary Report Query provides a summary pricing report for all line items shipped as of a given date. The date is within 60-120 days of the greatest ship date contained in the database.

1.2 Functional Query Definition

The query lists totals for extended price, discounted extended price, discounted extended price plus tax, average quantity, average extended price, and average discount. These aggregates are grouped by RETURNFLAG and LINESTATUS, and listed in ascending order of RETURNFLAG and LINESTATUS. A count of the number of line items in each group is included.

Copy
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 <= mdy (12, 01, 1998 ) - 90 units day
 group by
       l_returnflag,
       l_linestatus
 order by
       l_returnflag,
       l_linestatus;

1.3 Substitution Parameters

Values for the following substitution parameter must be generated and used to build the executable query text: 1. DELTA is randomly selected within [60. 120].

1998-12-01 is the highest possible ship date as defined in the database population. (This is ENDDATE - 30). The query will include all lineitems shipped before this date minus DELTA days. The intent is to choose DELTA so that between 95% and 97% of the rows in the table are scanned.

1.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  • 90

Sample Output

l_returnflag A
l_linestatus F
sum_qty 37734107.00
sum_base_price 56586554400.73
sum_disc_price 53758257134.87
sum_charge 55909065222.83
avg_qty 25.52
avg_price 38273.13
avg_disc .05
count_order 1478493

2 Q2 - Minimum Cost Supplier Query

This query finds which supplier should be selected to place an order for a given part in a given region

2.1 Business Question

The Minimum Cost Supplier Query finds, in a given region, for each part of a certain type and size, the supplier who can supply it at minimum cost. If several suppliers in that region offer the desired part type and size at the same (minimum) cost, the query lists the parts from suppliers with the 100 highest account balances. For each supplier, the query lists the supplier's account balance, name and nation; the part's number and manufacturer; the supplier's address, phone number and comment information.

2.2 Functional Query Definition

Return the first 100 selected rows

Copy
SELECT FIRST 100
     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 = 15
     AND p_type LIKE '%BRASS'
     AND s_nationkey = n_nationkey
     AND n_regionkey = r_regionkey
     AND r_name = 'EUROPE'
     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 = 'EUROPE'
     )
ORDER BY s_acctbal DESC, n_name, s_name, p_partkey

2.3 Substitution Parameters

Values for the following substitution parameter must be generated and used to build the executable query text:

  1. SIZE is randomly selected within [1. 50]
  2. TYPE is randomly selected within the list Syllable 3 defined for Types in TPCH Clause 4.2.2.13
  3. REGION is randomly selected within the list of values defined for R_NAME in 4.2.3.

2.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. SIZE = 15
  2. TYPE = BRASS
  3. REGION = EUROPE

Sample Output

s_acctbal 9938.53
s_name Supplier#000005359
n_name UNITED KINGDOM
p_partkey 185358
p_mfgr Manufacturer#4
s_address QKuHYh,vZGiwu2FWEJoLDx04
s_phone 33-429-790-6131
s_comment uriously regular requests hag

3 Q3 - Shipping Priority Query

This query retrieves the 10 unshipped orders with the highest value.

3.1 Business Question

The Shipping Priority Query retrieves the shipping priority and potential revenue, defined as the sum of l_extendedprice * (1-l_discount), of the orders having the largest revenue among those that had not been shipped as of a given date. Orders are listed in decreasing order of revenue. If more than 10 unshipped orders exist, only the 10 orders with the largest revenue are listed.

3.2 Functional Query Definition

Return the first 10 selected rows

Copy
SELECT FIRST 10
     l_orderkey,
     SUM(l_extendedprice * (1 - l_discount)) AS revenue,
     o_orderdate,
     o_shippriority
 FROM  customer, orders, lineitem
WHERE c_mktsegment = 'BUILDING'
  AND c_custkey = o_custkey
  AND l_orderkey = o_orderkey
  AND o_orderdate < MDY(3, 15, 1995)
  AND l_shipdate > MDY(3, 15, 1995)
GROUP BY l_orderkey, o_orderdate, o_shippriority
ORDER BY revenue DESC,  o_orderdate

3.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. SEGMENT is randomly selected within the list of values defined for Segments in Clause 4.2.2.13
  2. DATE is a randomly selected day within [1995-03-01 .. 1995-03-31].

3.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. SEGMENT = BUILDING
  2. DATE = 1995-03-15

Sample Output

l_orderkey 2456423
revenue 406181,011100000
o_orderdate 05-03-1995
p_paro_shipprioritytkey 0

4 Q4 - Order Priority Checking Query

This query determines how well the order priority system is working and gives an assessment of customer satisfaction.

4.1 Business Question

The Order Priority Checking Query counts the number of orders ordered in a given quarter of a given year in which at least one lineitem was received by the customer later than its committed date. The query lists the count of such orders for each order priority sorted in ascending priority order.

4.2 Functional Query Definition

Copy
SELECT o_orderpriority, COUNT(*) AS order_count
  FROM orders
 WHERE o_orderdate >= MDY (7, 1, 1993)
   AND o_orderdate < MDY (7, 1, 1993) + 3 UNITS MONTH
   AND EXISTS (
      SELECT *
        FROM lineitem
       WHERE l_orderkey = o_orderkey
         AND l_commitdate < l_receiptdate
     )
GROUP BY o_orderpriority
ORDER BY o_orderpriority

4.3 Substitution Parameters

Values for the following substitution parameter must be generated and used to build the executable query text:

  1. DATE is the first day of a randomly selected month between the first month of 1993 and the 10th month of 1997

4.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. DATE = 1993-07-01

Sample Output

o_orderpriority 1-URGENT
order_count 10594

5 Q5 - Local Supplier Volume Query

This query lists the revenue volume done through local suppliers.

5.1 Business Question

The Local Supplier Volume Query lists for each nation in a region the revenue volume that resulted from lineitem transactions in which the customer ordering parts and the supplier filling them were both within that nation. The query is run in order to determine whether to institute local distribution centers in a given region. The query considers only parts ordered in a given year. The query displays the nations and revenue volume in descending order by revenue. Revenue volume for all qualifying lineitems in a particular nation is defined as sum(l_extendedprice * (1 - l_discount)).

5.2 Functional Query Definition

Copy
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 = 'ASIA'
   AND o_orderdate >= MDY(1,1,1994)
   AND o_orderdate < MDY(1,1,1994) + 1 UNITS YEAR
GROUP BY n_name
ORDER BY revenue DESC

5.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. REGION is randomly selected within the list of values defined for R_NAME in C;aise 4.2.3
  2. DATE is the first of January of a randomly selected year within [1993 .. 1997]

5.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. REGION = ASIA
  2. DATE = 1994-01-01

Sample Output

n_name INDONESIA
revenue 55502041,1697000

6 Q6 - Forecasting Revenue Change Query

This query quantifies the amount of revenue increase that would have resulted from eliminating certain companywide discounts in a given percentage range in a given year. Asking this type of "what if" query can be used to look for ways to increase revenues.

6.1 Business Question

The Forecasting Revenue Change Query considers all the lineitems shipped in a given year with discounts between DISCOUNT-0.01 and DISCOUNT+0.01. The query lists the amount by which the total revenue would have increased if these discounts had been eliminated for lineitems with l_quantity less than quantity. Note that the potential revenue increase is equal to the sum of [l_extendedprice * l_discount] for all lineitems with discounts and quantities in the qualifying range.

6.2 Functional Query Definition

Copy
SELECT
     SUM(l_extendedprice * l_discount) AS revenue
FROM
     lineitem
WHERE
     l_shipdate >= MDY(1,1,1994)
     AND l_shipdate < MDY(1,1,1994) + 1 UNITS YEAR
     AND l_discount BETWEEN .06 - 0.01 AND .06 + 0.010001
     AND l_quantity < 24

6.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. DATE is the first of January of a randomly selected year within [1993 .. 1997]
  2. DISCOUNT is randomly selected within [0.02 .. 0.09]
  3. QUANTITY is randomly selected within [24 .. 25]

6.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. DATE = 1994-01-01
  2. DISCOUNT = 0.06
  3. QUANTITY = 24

Sample Output

revenue 123141078,2283

7 Q7 - Volume Shipping Query

This query determines the value of goods shipped between certain nations to help in the re-negotiation of shipping contracts.

7.1 Business Question

The Volume Shipping Query finds, for two given nations, the gross discounted revenues derived from lineitems in which parts were shipped from a supplier in either nation to a customer in the other nation during 1995 and 1996. The query lists the supplier nation, the customer nation, the year, and the revenue from shipments that took place in that year. The query orders the answer by Supplier nation, Customer nation, and year (all ascending).

7.2 Functional Query Definition

Copy
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,
			YEAR(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 = 'FRANCE' AND n2.n_name = 'GERMANY')
				OR (n1.n_name = 'GERMANY' AND n2.n_name = 'FRANCE')
			)
			AND l_shipdate BETWEEN MDY(1,1,1995) AND MDY(12,31,1996)
     ) AS shipping
GROUP BY
     supp_nation,
     cust_nation,
     l_year
ORDER BY
     supp_nation,
     cust_nation,
     l_year

7.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. NATION1 is randomly selected within the list of values defined for N_NAME in Clause 4.2.3
  2. NATION2 is randomly selected within the list of values defined for N_NAME in Clause 4.2.3 and must be different from the value selected for NATION1 in item 1 above.
  3. QUANTITY is randomly selected within [24 .. 25]

7.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. NATION1 = FRANCE
  2. NATION2 = GERMANY

Sample Output

supp_nation FRANCE
cust_nation GERMANY
l_year 1995
revenue 54639732,7336000

8 Q8 - National Market Share Query

This query determines how the market share of a given nation within a given region has changed over two years for a given part type.

8.1 Business Question

The market share for a given nation within a given region is defined as the fraction of the revenue, the sum of [l_extendedprice * (1-l_discount)], from the products of a specified type in that region that was supplied by suppliers from the given nation. The query determines this for the years 1995 and 1996 presented in this order.

8.2 Functional Query Definition

Copy
SELECT
     o_year,
     SUM(CASE
		WHEN nation = 'BRAZIL' THEN volume
		ELSE 0
     END) / SUM(volume) AS mkt_share
FROM
     (
		SELECT
			YEAR(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 = 'AMERICA'
			AND s_nationkey = n2.n_nationkey
			AND o_orderdate BETWEEN CAST ('1995-01-01' AS DATE) AND CAST ('1996-12-31' AS DATE)
			AND p_type = 'ECONOMY ANODIZED STEEL'
     ) AS all_nations
GROUP BY
     o_year
ORDER BY
     o_year

8.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. NATION is randomly selected within the list of values defined for N_NAME in Clause 4.2.3
  2. REGION is the value defined in Clause 4.2.3 for R_NAME where R_REGIONKEY corresponds to N_REGIONKEY for the selected NATION in item 1 above.
  3. TYPE is randomly selected within the list of 3-syllable strings defined for Types in Clause 4.2.2.13

8.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. NATION = BRAZIL
  2. REGION = AMERICA
  3. TYPE = ECONOMY ANODIZED STEEL

Sample Output

o_year 1995
mkt_share 0,03443589040665

9 Q9 - Product Type Profit Measure Query

This query determines how much profit is made on a given line of parts, broken out by supplier nation and year.

9.1 Business Question

The Product Type Profit Measure Query finds, for each nation and each year, the profit for all parts ordered in that year that contain a specified substring in their names and that were filled by a supplier in that nation. The profit is defined as the sum of [(l_extendedprice*(1-l_discount)) - (ps_supplycost * l_quantity)] for all lineitems describing parts in the specified line. The query lists the nations in ascending alphabetical order and, for each nation, the year and profit in descending order by year (most recent first).

9.2 Functional Query Definition

Copy
SELECT
     nation,
     o_year,
     SUM(amount) AS sum_profit
FROM
     (
		SELECT
			n_name AS nation,
			YEAR(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 '%green%'
     ) AS profit
GROUP BY
     nation,
     o_year
ORDER BY
     nation,
     o_year DESC

9.3 Substitution Parameters

Values for the following substitution parameter must be generated and used to build the executable query text:

  1. COLOR is randomly selected within the list of values defined for the generation of P_NAME in Clause 4.2.3

9.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. COLOR = green

Sample Output

nation ALGERIA
o_year 1998
sum_profit 27136900,1803000

10 Q10 - Returned Item Reporting Query

The query identifies customers who might be having problems with the parts that are shipped to them.

10.1 Business Question

The Returned Item Reporting Query finds the top 20 customers, in terms of their effect on lost revenue for a given quarter, who have returned parts. The query considers only parts that were ordered in the specified quarter. The query lists the customer's name, address, nation, phone number, account balance, comment information and revenue lost. The customers are listed in descending order of lost revenue. Revenue lost is defined as sum(l_extendedprice*(1-l_discount)) for all qualifying lineitems.

10.2 Functional Query Definition

Return the first 20 selected rows

Copy
SELECT FIRST 20
     c_custkey,
     c_name,
     SUM(l_extendedprice * (1 - l_discount)) AS revenue,
     c_acctbal,
     n_name,
     c_address,
     c_phone,
     c_comment
FROM
     customer,
     orders,
     lineitem,
     nation
WHERE
     c_custkey = o_custkey
     AND l_orderkey = o_orderkey
     AND o_orderdate >= MDY  (10,1,1993)
     AND o_orderdate < MDY(10,1,1993) + 3 UNITS MONTH
     AND l_returnflag = 'R'
     AND c_nationkey = n_nationkey
GROUP BY
     c_custkey,
     c_name,
     c_acctbal,
     c_phone,
     n_name,
     c_address,
     c_comment
ORDER BY
     revenue DESC

10.3 Substitution Parameters

Values for the following substitution parameter must be generated and used to build the executable query text:

  1. DATE is the first day of a randomly selected month from the second month of 1993 to the first month of 1995

10.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. DATE = 1993-10-01

Sample Output

c_custkey 57040
c_name Customer#000057040
revenue 734235,245500000
c_acctbal 632,87
n_name JAPAN
c_address Eioyzjf4pp
c_phone 22-895-641-3466
c_comment sits. slyly regular requests sleep alongside of the regular inst

11 Q11 - Important Stock Identification Query

This query finds the most important subset of suppliers' stock in a given nation.

11.1 Business Question

The Important Stock Identification Query finds, from scanning the available stock of suppliers in a given nation, all the parts that represent a significant percentage of the total value of all available parts. The query displays the part number and the value of those parts in descending order of value.

11.2 Functional Query Definition

Copy
SELECT
     FIRST 10
     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.0001000000e-2
			FROM
				partsupp,
				supplier,
				nation
			WHERE
				ps_suppkey = s_suppkey
				AND s_nationkey = n_nationkey
				AND n_name = 'GERMANY'
		)
ORDER BY
     value DESC

11.3 Substitution Parameters

Values for the following substitution parameter must be generated and used to build the executable query text:

  1. NATION is randomly selected within the list of values defined for N_NAME in Clause 4.2.3
  2. FRACTION is chosen as 0.0001 / SF

11.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. NATION = GERMANY
  2. FRACTION = 0.0001

Sample Output

ps_partkey 129760
value 17538456,86

12 Q12 - Shipping Modes and Order Priority Query

This query determines whether selecting less expensive modes of shipping is negatively affecting the critical-priority orders by causing more parts to be received by customers after the committed date.

12.1 Business Question

The Shipping Modes and Order Priority Query counts, by ship mode, for lineitems actually received by customers in a given year, the number of lineitems belonging to orders for which the l_receiptdate exceeds the l_commitdate for two different specified ship modes. Only lineitems that were actually shipped before the l_commitdate are considered. The late lineitems are partitioned into two groups, those with priority URGENT or HIGH, and those with a priority other than URGENT or HIGH.

12.2 Functional Query Definition

Copy
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 >= MDY(1,1, 1994)
     AND l_receiptdate < MDY(1,1,1994) + 1 UNITS YEAR
GROUP BY
     l_shipmode
ORDER BY
     l_shipmode

12.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. SHIPMODE1 is randomly selected within the list of values defined for Modes in Clause 4.2.2.13
  2. SHIPMODE2 is randomly selected within the list of values defined for Modes in Clause 4.2.2.13 and must be different from the value selected for SHIPMODE1 in item 1
  3. DATE is the first of January of a randomly selected year within [1993 .. 1997]

12.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. SHIPMODE1 = MAIL
  2. SHIPMODE2 = SHIP
  3. DATE = 1994-01-01

Sample Output

l_shipmode MAIL
high_line_count 6202
low_line_count 9324

13 Q13 - Customer Distribution Query

This query seeks relationships between customers and the size of their orders.

13.1 Business Question

This query determines the distribution of customers by the number of orders they have made, including customers who have no record of orders, past or present. It counts and reports how many customers have no orders, how many have 1, 2, 3, etc. A check is made to ensure that the orders counted do not fall into one of several special categories of orders. Special categories are identified in the order comment column by looking for a particular pattern.

13.2 Functional Query Definition

Copy
SELECT
          c_count,
          COUNT(*) AS custdist
  FROM (
          SELECT
                  c_custkey,
                  COUNT(o_orderkey) AS c_count
          FROM
                  (SELECT * FROM customer
                  LEFT OUTER JOIN orders ON
                    c_custkey = o_custkey AND
                    o_comment NOT LIKE '%special%requests%') c_customer
          GROUP BY
                  c_custkey
          ) c_orders
  GROUP BY
          c_count
  ORDER BY
          custdist DESC,
          c_count DESC

13.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. WORD1 is randomly selected from 4 possible values: special, pending, unusual, express
  2. WORD2 is randomly selected from 4 possible values: packages, requests, accounts, deposits

13.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. WORD1 = special
  2. WORD2 = requests

Sample Output

c_count 9
custdist 6641

14 Q14 - Promotion Effect Query

This query monitors the market response to a promotion such as TV advertisements or a special campaign

14.1 Business Question

The Promotion Effect Query determines what percentage of the revenue in a given year and month was derived from promotional parts. The query considers only parts actually shipped in that month and gives the percentage. Revenue is defined as (l_extendedprice * (1-l_discount)).

14.2 Functional Query Definition

Copy
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 >= MDY(9,1,1995)
     AND l_shipdate < MDY(9,1,1995) + 1 UNITS MONTH

14.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. DATE is the first day of a month randomly selected from a random year within [1993 .. 1997]

14.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. DATE = 1995-09-01

Sample Output

promo_revenue 16,3807786263955

15 Q15

16 Q16 - Parts/Supplier Relationship Query

This query finds out how many suppliers can supply parts with given attributes. It might be used, for example, to determine whether there is a sufficient number of suppliers for heavily ordered parts

16.1 Business Question

The Parts/Supplier Relationship Query counts the number of suppliers who can supply parts that satisfy a particular customer's requirements. The customer is interested in parts of eight different sizes as long as they are not of a given type, not of a given brand, and not from a supplier who has had complaints registered at the Better Business Bureau. Results must be presented in descending count and ascending brand, type, and size.

16.2 Functional Query Definition

Copy
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

16.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. BRAND = Brand#MN where M and N are two single character strings representing two numbers randomly and independently selected within [1 .. 5];
  2. TYPE is made of the first 2 syllables of a string randomly selected within the list of 3-syllable strings defined for Types in Clause 4.2.2.13;
  3. SIZE1 is randomly selected as a set of eight different values within [1 .. 50];
  4. SIZE2 is randomly selected as a set of eight different values within [1 .. 50];
  5. SIZE3 is randomly selected as a set of eight different values within [1 .. 50];
  6. SIZE4 is randomly selected as a set of eight different values within [1 .. 50];
  7. SIZE5 is randomly selected as a set of eight different values within [1 .. 50];
  8. SIZE6 is randomly selected as a set of eight different values within [1 .. 50];
  9. SIZE7 is randomly selected as a set of eight different values within [1 .. 50];
  10. SIZE8 is randomly selected as a set of eight different values within [1 .. 50].

16.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. BRAND = Brand#45
  2. TYPE = MEDIUM POLISHED .
  3. SIZE1 = 49
  4. SIZE2 = 14
  5. SIZE3 = 23
  6. SIZE4 = 45
  7. SIZE5 = 19
  8. SIZE6 = 3
  9. SIZE7 = 36
  10. SIZE8 = 9.

Sample Output

p_brand Brand#41
p_type MEDIUM BRUSHED TIN
p_size 3
supplier_cnt 28

17 Q17 - Small-Quantity-Order Revenue Query

This query determines how much average yearly revenue would be lost if orders were no longer filled for small quantities of certain parts. This may reduce overhead expenses by concentrating sales on larger shipments.

17.1 Business Question

The Small-Quantity-Order Revenue Query considers parts of a given brand and with a given container type and determines the average lineitem quantity of such parts ordered for all orders (past and pending) in the 7-year database. What would be the average yearly gross (undiscounted) loss in revenue if orders for these parts with a quantity of less than 20% of this average were no longer taken?

17.2 Functional Query Definition

Copy
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
			2e-1 * AVG(l_quantity)
		FROM
			lineitem
		WHERE
			l_partkey = p_partkey
     )

17.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. BRAND = 'Brand#MN' where MN is a two character string representing two numbers randomly and independently selected within [1 .. 5];
  2. CONTAINER is randomly selected within the list of 2-syllable strings defined for Containers in Clause 4.2.2.13.

17.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. BRAND = Brand#23;
  2. CONTAINER = MED BOX.

Sample Output

avg_yearly 348406,054285714

18 Q18 - Large Volume Customer Query

The Large Volume Customer Query ranks customers based on their having placed a large quantity order. Large quantity orders are defined as those orders whose total quantity is above a certain level.

18.1 Business Question

The Large Volume Customer Query finds a list of the top 100 customers who have ever placed large quantity orders.

The query lists the customer name, customer key, the order key, date and total price and the quantity for the order.

18.2 Functional Query Definition

Copy
select FIRST 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

18.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. QUANTITY is randomly selected within [312..315].

18.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. QUANTITY = 300

Sample Output

c_name Customer#000128120
c_custkey 128120
o_orderkey 4722021
o_orderdate 07-04-1994
o_totalprice 544089,09
(sum) 323,00

19 Q19 - Discounted Revenue Query

The Discounted Revenue Query reports the gross discounted revenue attributed to the sale of selected parts handled in a particular manner. This query is an example of code such as might be produced programmatically by a data mining tool.

19.1 Business Question

The Discounted Revenue query finds the gross discounted revenue for all orders for three different types of parts that were shipped by air and delivered in person. Parts are selected based on the combination of specific brands, a list of containers, and a range of sizes.

19.2 Functional Query Definition

Copy
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'
     )

19.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. QUANTITY1 is randomly selected within [1..10]
  2. QUANTITY2 is randomly selected within [10..20].
  3. QUANTITY3 is randomly selected within [20..30
  4. BRAND1, BRAND2, BRAND3 = 'Brand#MN' where each MN is a two character string representing two numbers randomly and independently selected within [1 .. 5]

19.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. QUANTITY1 = 1
  2. QUANTITY2 = 10
  3. QUANTITY3 = 20.
  4. BRAND1 = Brand#12.
  5. BRAND2 = Brand#23.
  6. BRAND3 = Brand#34

Sample Output

revenue 3083843,05780000

20 Q20 - Potential Part Promotion Query

The Potential Part Promotion Query identifies suppliers in a particular nation having selected parts that may be candidates for a promotional offer.

20.1 Business Question

The Potential Part Promotion query identifies suppliers who have an excess of a given part available; an excess is defined to be more than 50% of the parts like the given part that the supplier shipped in a given year for a given nation. Only parts whose names share a certain naming convention are considered.

20.2 Functional Query Definition

Copy
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 >= MDY(1,1,1994)
					AND l_shipdate < MDY(1,1,1994) + 1 UNITS YEAR
			)
     )
     AND s_nationkey = n_nationkey
     AND n_name = 'CANADA'
ORDER BY
     s_name

20.3 Substitution Parameters

Values for the following substitution parameters must be generated and used to build the executable query text:

  1. COLOR is randomly selected within the list of values defined for the generation of P_NAME.
  2. DATE is the first of January of a randomly selected year within 1993..1997.
  3. NATION is randomly selected within the list of values defined for N_NAME in Clause 4.2.3.

20.4 Query Validation

For validation against the qualification database the query must be executed using the following values for substitution parameters and must produce the following output data:

Values for substitution parameters:

  1. COLOR = forest.
  2. DATE = 1994-01-01.
  3. QUANTITY3 = 20.
  4. NATION = CANADA.

Sample Output

s_name Supplier#000000020
s_address iybAE,RmTymrZVYaFZva2SH,j