59 lines
2.4 KiB
SQL
59 lines
2.4 KiB
SQL
-- From:
|
|
-- http://www.sqlserver-dba.com/2011/09/this-is-a-followup-on-my-earlier-post-of-sql-server-test-data-generation-testing-tools-i-had-some-requests-for-my-set-up-pr.html
|
|
|
|
-- TPC_H Query 11 - Important Stock Identification
|
|
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 = 'GERMANY'
|
|
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 = 'GERMANY')
|
|
ORDER BY VALUE DESC;
|
|
|
|
|
|
-- TPC_H Query 12 - Shipping Modes and Order Priority
|
|
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 >= '1994-01-01'
|
|
AND L_RECEIPTDATE < dateadd(mm, 1, cast('1995-09-01' as datetime))
|
|
GROUP BY L_SHIPMODE
|
|
ORDER BY L_SHIPMODE;
|
|
|
|
|
|
-- TPC_H Query 13 - Customer Distribution
|
|
SELECT C_COUNT, COUNT(*) AS CUSTDIST
|
|
FROM (SELECT C_CUSTKEY, COUNT(O_ORDERKEY)
|
|
FROM CUSTOMER left outer join ORDERS on C_CUSTKEY = O_CUSTKEY
|
|
AND O_COMMENT not like '%%special%%requests%%'
|
|
GROUP BY C_CUSTKEY) AS C_ORDERS
|
|
GROUP BY C_COUNT
|
|
ORDER BY CUSTDIST DESC, C_COUNT DESC;
|
|
|
|
|
|
-- TPC_H Query 14 - Promotion Effect
|
|
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 >= '1995-09-01' AND L_SHIPDATE < dateadd(mm, 1, '1995-09-01');
|
|
|
|
|
|
-- TPC_H Query 15.1 - Create View for Top Supplier Query
|
|
CREATE VIEW REVENUE0 (SUPPLIER_NO, TOTAL_REVENUE) AS
|
|
SELECT L_SUPPKEY, SUM(L_EXTENDEDPRICE*(1-L_DISCOUNT)) FROM LINEITEM
|
|
WHERE L_SHIPDATE >= '1996-01-01' AND L_SHIPDATE < dateadd(mm, 3, cast('1996-01-01' as datetime))
|
|
GROUP BY L_SUPPKEY;
|
|
|
|
|
|
-- TPC_H Query 15.2 - Top Supplier
|
|
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;
|
|
|
|
-- TPC_H Query 15.3 - Drop View
|
|
DROP VIEW REVENUE0;
|