From a19c4877662f6b244d4bbadd7350d1d480a37a8e Mon Sep 17 00:00:00 2001 From: Alexander Bayandin Date: Thu, 8 Dec 2022 15:32:49 +0000 Subject: [PATCH] Nightly Benchmarks: add TPC-H benchmark (#2978) Ref: https://www.tpc.org/tpch/ --- .github/workflows/benchmarking.yml | 115 +++++++++++++++++- test_runner/performance/test_perf_olap.py | 35 ++++++ .../performance/tpc-h/create-indexes.sql | 43 +++++++ .../performance/tpc-h/create-schema.sql | 69 +++++++++++ test_runner/performance/tpc-h/queries/1.sql | 27 ++++ test_runner/performance/tpc-h/queries/10.sql | 38 ++++++ test_runner/performance/tpc-h/queries/11.sql | 34 ++++++ test_runner/performance/tpc-h/queries/12.sql | 35 ++++++ test_runner/performance/tpc-h/queries/13.sql | 27 ++++ test_runner/performance/tpc-h/queries/14.sql | 20 +++ test_runner/performance/tpc-h/queries/15.sql | 40 ++++++ test_runner/performance/tpc-h/queries/16.sql | 37 ++++++ test_runner/performance/tpc-h/queries/17.sql | 25 ++++ test_runner/performance/tpc-h/queries/18.sql | 39 ++++++ test_runner/performance/tpc-h/queries/19.sql | 42 +++++++ test_runner/performance/tpc-h/queries/2.sql | 50 ++++++++ test_runner/performance/tpc-h/queries/20.sql | 44 +++++++ test_runner/performance/tpc-h/queries/21.sql | 46 +++++++ test_runner/performance/tpc-h/queries/22.sql | 44 +++++++ test_runner/performance/tpc-h/queries/3.sql | 29 +++++ test_runner/performance/tpc-h/queries/4.sql | 28 +++++ test_runner/performance/tpc-h/queries/5.sql | 31 +++++ test_runner/performance/tpc-h/queries/6.sql | 16 +++ test_runner/performance/tpc-h/queries/7.sql | 46 +++++++ test_runner/performance/tpc-h/queries/8.sql | 44 +++++++ test_runner/performance/tpc-h/queries/9.sql | 39 ++++++ 26 files changed, 1042 insertions(+), 1 deletion(-) create mode 100644 test_runner/performance/tpc-h/create-indexes.sql create mode 100644 test_runner/performance/tpc-h/create-schema.sql create mode 100644 test_runner/performance/tpc-h/queries/1.sql create mode 100644 test_runner/performance/tpc-h/queries/10.sql create mode 100644 test_runner/performance/tpc-h/queries/11.sql create mode 100644 test_runner/performance/tpc-h/queries/12.sql create mode 100644 test_runner/performance/tpc-h/queries/13.sql create mode 100644 test_runner/performance/tpc-h/queries/14.sql create mode 100644 test_runner/performance/tpc-h/queries/15.sql create mode 100644 test_runner/performance/tpc-h/queries/16.sql create mode 100644 test_runner/performance/tpc-h/queries/17.sql create mode 100644 test_runner/performance/tpc-h/queries/18.sql create mode 100644 test_runner/performance/tpc-h/queries/19.sql create mode 100644 test_runner/performance/tpc-h/queries/2.sql create mode 100644 test_runner/performance/tpc-h/queries/20.sql create mode 100644 test_runner/performance/tpc-h/queries/21.sql create mode 100644 test_runner/performance/tpc-h/queries/22.sql create mode 100644 test_runner/performance/tpc-h/queries/3.sql create mode 100644 test_runner/performance/tpc-h/queries/4.sql create mode 100644 test_runner/performance/tpc-h/queries/5.sql create mode 100644 test_runner/performance/tpc-h/queries/6.sql create mode 100644 test_runner/performance/tpc-h/queries/7.sql create mode 100644 test_runner/performance/tpc-h/queries/8.sql create mode 100644 test_runner/performance/tpc-h/queries/9.sql diff --git a/.github/workflows/benchmarking.yml b/.github/workflows/benchmarking.yml index ec2bea9058..eb9ba70371 100644 --- a/.github/workflows/benchmarking.yml +++ b/.github/workflows/benchmarking.yml @@ -385,7 +385,7 @@ jobs: env: BENCHMARK_CONNSTR: ${{ steps.set-up-connstr.outputs.connstr }} - - name: Benchmark clickbench + - name: ClickBench benchmark uses: ./.github/actions/run-python-test-set with: build_type: ${{ env.BUILD_TYPE }} @@ -413,3 +413,116 @@ jobs: slack-message: "Periodic OLAP perf testing ${{ matrix.platform }}: ${{ job.status }}\n${{ github.server_url }}/${{ github.repository }}/actions/runs/${{ github.run_id }}" env: SLACK_BOT_TOKEN: ${{ secrets.SLACK_BOT_TOKEN }} + + tpch-compare: + # TCP-H DB for rds-aurora and rds-Postgres deployed to the same clusters + # we use for performance testing in pgbench-compare & clickbench-compare. + # Run this job only when clickbench-compare is finished to avoid the intersection. + # We might change it after https://github.com/neondatabase/neon/issues/2900. + # + # *_TPCH_S10_CONNSTR: DB generated with scale factor 10 (~10 GB) + if: success() || failure() + needs: [ clickbench-compare ] + + strategy: + fail-fast: false + matrix: + # neon-captest-prefetch: We have pre-created projects with prefetch enabled + # rds-aurora: Aurora Postgres Serverless v2 with autoscaling from 0.5 to 2 ACUs + # rds-postgres: RDS Postgres db.m5.large instance (2 vCPU, 8 GiB) with gp3 EBS storage + platform: [ neon-captest-prefetch, rds-postgres, rds-aurora ] + + env: + POSTGRES_DISTRIB_DIR: /tmp/neon/pg_install + DEFAULT_PG_VERSION: 14 + TEST_OUTPUT: /tmp/test_output + BUILD_TYPE: remote + SAVE_PERF_REPORT: ${{ github.event.inputs.save_perf_report || ( github.ref == 'refs/heads/main' ) }} + PLATFORM: ${{ matrix.platform }} + + # NOTE: Here we use non-standadard `captest` runner (instead of `dev`) which is located in us-east-2 region. + # We will move the rest of benchmarking jobs to staging in https://github.com/neondatabase/neon/pull/2838 + runs-on: [ self-hosted, captest, x64 ] + container: + image: 369495373322.dkr.ecr.eu-central-1.amazonaws.com/rustlegacy:pinned + options: --init + + timeout-minutes: 360 # 6h + + steps: + - uses: actions/checkout@v3 + + - name: Download Neon artifact + uses: ./.github/actions/download + with: + name: neon-${{ runner.os }}-release-artifact + path: /tmp/neon/ + prefix: latest + + - name: Add Postgres binaries to PATH + run: | + ${POSTGRES_DISTRIB_DIR}/v${DEFAULT_PG_VERSION}/bin/pgbench --version + echo "${POSTGRES_DISTRIB_DIR}/v${DEFAULT_PG_VERSION}/bin" >> $GITHUB_PATH + + - name: Set up Connection String + id: set-up-connstr + run: | + case "${PLATFORM}" in + neon-captest-prefetch) + CONNSTR=${{ secrets.BENCHMARK_CAPTEST_TPCH_S10_CONNSTR }} + ;; + rds-aurora) + CONNSTR=${{ secrets.BENCHMARK_RDS_AURORA_TPCH_S10_CONNSTR }} + ;; + rds-postgres) + CONNSTR=${{ secrets.BENCHMARK_RDS_POSTGRES_TPCH_S10_CONNSTR }} + ;; + *) + echo 2>&1 "Unknown PLATFORM=${PLATFORM}. Allowed only 'neon-captest-prefetch', 'rds-aurora', or 'rds-postgres'" + exit 1 + ;; + esac + + echo "connstr=${CONNSTR}" >> $GITHUB_OUTPUT + + psql ${CONNSTR} -c "SELECT version();" + + - name: Set database options + if: matrix.platform == 'neon-captest-prefetch' + run: | + DB_NAME=$(psql ${BENCHMARK_CONNSTR} --no-align --quiet -t -c "SELECT current_database()") + + psql ${BENCHMARK_CONNSTR} -c "ALTER DATABASE ${DB_NAME} SET enable_seqscan_prefetch=on" + psql ${BENCHMARK_CONNSTR} -c "ALTER DATABASE ${DB_NAME} SET effective_io_concurrency=32" + psql ${BENCHMARK_CONNSTR} -c "ALTER DATABASE ${DB_NAME} SET maintenance_io_concurrency=32" + env: + BENCHMARK_CONNSTR: ${{ steps.set-up-connstr.outputs.connstr }} + + - name: Run TPC-H benchmark + uses: ./.github/actions/run-python-test-set + with: + build_type: ${{ env.BUILD_TYPE }} + test_selection: performance/test_perf_olap.py + run_in_parallel: false + save_perf_report: ${{ env.SAVE_PERF_REPORT }} + extra_params: -m remote_cluster --timeout 21600 -k test_tpch + env: + VIP_VAP_ACCESS_TOKEN: "${{ secrets.VIP_VAP_ACCESS_TOKEN }}" + PERF_TEST_RESULT_CONNSTR: "${{ secrets.PERF_TEST_RESULT_CONNSTR }}" + BENCHMARK_CONNSTR: ${{ steps.set-up-connstr.outputs.connstr }} + + - name: Create Allure report + if: success() || failure() + uses: ./.github/actions/allure-report + with: + action: generate + build_type: ${{ env.BUILD_TYPE }} + + - name: Post to a Slack channel + if: ${{ github.event.schedule && failure() }} + uses: slackapi/slack-github-action@v1 + with: + channel-id: "C033QLM5P7D" # dev-staging-stream + slack-message: "Periodic TPC-H perf testing ${{ matrix.platform }}: ${{ job.status }}\n${{ github.server_url }}/${{ github.repository }}/actions/runs/${{ github.run_id }}" + env: + SLACK_BOT_TOKEN: ${{ secrets.SLACK_BOT_TOKEN }} diff --git a/test_runner/performance/test_perf_olap.py b/test_runner/performance/test_perf_olap.py index 84693325c0..8c3b6e57ff 100644 --- a/test_runner/performance/test_perf_olap.py +++ b/test_runner/performance/test_perf_olap.py @@ -2,8 +2,10 @@ from dataclasses import dataclass from typing import Dict, Tuple import pytest +from _pytest.mark import ParameterSet from fixtures.compare_fixtures import RemoteCompare from fixtures.log_helper import log +from fixtures.utils import get_self_dir @dataclass @@ -109,3 +111,36 @@ def test_clickbench(query: LabelledQuery, remote_compare: RemoteCompare): """ run_psql(remote_compare, query, times=3) + + +def tpch_queuies() -> Tuple[ParameterSet, ...]: + """ + A list of queries to run for the TPC-H benchmark. + - querues in returning tuple are ordered by the query number + - pytest parameters id is adjusted to match the query id (the numbering starts from 1) + """ + queries_dir = get_self_dir().parent / "performance" / "tpc-h" / "queries" + assert queries_dir.exists(), f"TPC-H queries dir not found: {queries_dir}" + + return tuple( + pytest.param(LabelledQuery(f"Q{f.stem}", f.read_text()), id=f"query{f.stem}") + for f in sorted(queries_dir.glob("*.sql"), key=lambda f: int(f.stem)) + ) + + +@pytest.mark.parametrize("query", tpch_queuies()) +@pytest.mark.remote_cluster +def test_tpch(query: LabelledQuery, remote_compare: RemoteCompare): + """ + TCP-H Benchmark + + The DB prepared manually in advance: + - schema: test_runner/performance/tpc-h/create-schema.sql + - indexes: test_runner/performance/tpc-h/create-indexes.sql + - data generated by `dbgen` program of the official TPC-H benchmark + - `VACUUM (FREEZE, PARALLEL 0);` + + For query generation `1669822882` is used as a seed to the RNG + """ + + run_psql(remote_compare, query, times=1) diff --git a/test_runner/performance/tpc-h/create-indexes.sql b/test_runner/performance/tpc-h/create-indexes.sql new file mode 100644 index 0000000000..590a9c1900 --- /dev/null +++ b/test_runner/performance/tpc-h/create-indexes.sql @@ -0,0 +1,43 @@ +-- Section 1.4.2.2 + +ALTER TABLE part ADD PRIMARY KEY (p_partkey); +ALTER TABLE supplier ADD PRIMARY KEY (s_suppkey); +ALTER TABLE partsupp ADD PRIMARY KEY (ps_partkey, ps_suppkey); +ALTER TABLE customer ADD PRIMARY KEY (c_custkey); +ALTER TABLE orders ADD PRIMARY KEY (o_orderkey); +ALTER TABLE lineitem ADD PRIMARY KEY (l_orderkey, l_linenumber); +ALTER TABLE nation ADD PRIMARY KEY (n_nationkey); +ALTER TABLE region ADD PRIMARY KEY (r_regionkey); + +-- Section 1.4.2.3 + +CREATE INDEX ON supplier USING btree (s_nationkey); +ALTER TABLE supplier ADD FOREIGN KEY (s_nationkey) REFERENCES nation (n_nationkey); + +/* IGNORE: implied by primary key */ +-- CREATE INDEX ON partsupp USING btree (ps_partkey); +CREATE INDEX ON partsupp USING btree (ps_suppkey); +ALTER TABLE partsupp ADD FOREIGN KEY (ps_partkey) REFERENCES part (p_partkey); +ALTER TABLE partsupp ADD FOREIGN KEY (ps_suppkey) REFERENCES supplier (s_suppkey); + +CREATE INDEX ON customer USING btree (c_nationkey); +ALTER TABLE customer ADD FOREIGN KEY (c_nationkey) REFERENCES nation (n_nationkey); + +CREATE INDEX ON orders USING btree (o_custkey); +ALTER TABLE orders ADD FOREIGN KEY (o_custkey) REFERENCES customer (c_custkey); + +/* IGNORE: implied by primary key */ +-- CREATE INDEX ON lineitem USING btree (l_orderkey); +CREATE INDEX ON lineitem USING btree (l_partkey, l_suppkey); +CREATE INDEX ON lineitem USING btree (l_suppkey); +ALTER TABLE lineitem ADD FOREIGN KEY (l_orderkey) REFERENCES orders (o_orderkey); +ALTER TABLE lineitem ADD FOREIGN KEY (l_partkey) REFERENCES part (p_partkey); +ALTER TABLE lineitem ADD FOREIGN KEY (l_suppkey) REFERENCES supplier (s_suppkey); +ALTER TABLE lineitem ADD FOREIGN KEY (l_partkey, l_suppkey) REFERENCES partsupp (ps_partkey, ps_suppkey); + +CREATE INDEX ON nation USING btree (n_regionkey); +ALTER TABLE nation ADD FOREIGN KEY (n_regionkey) REFERENCES region (r_regionkey); + +-- Section 1.4.2.4 + +ALTER TABLE lineitem ADD CHECK (l_shipdate <= l_receiptdate); diff --git a/test_runner/performance/tpc-h/create-schema.sql b/test_runner/performance/tpc-h/create-schema.sql new file mode 100644 index 0000000000..4293951aa1 --- /dev/null +++ b/test_runner/performance/tpc-h/create-schema.sql @@ -0,0 +1,69 @@ +-- Sccsid: @(#)dss.ddl 2.1.8.1 +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); diff --git a/test_runner/performance/tpc-h/queries/1.sql b/test_runner/performance/tpc-h/queries/1.sql new file mode 100644 index 0000000000..2e1967fec8 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/1.sql @@ -0,0 +1,27 @@ +-- $ID$ +-- TPC-H/TPC-R Pricing Summary Report Query (Q1) +-- Functional Query Definition +-- Approved February 1998 + + +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 '89' day +group by + l_returnflag, + l_linestatus +order by + l_returnflag, + l_linestatus; diff --git a/test_runner/performance/tpc-h/queries/10.sql b/test_runner/performance/tpc-h/queries/10.sql new file mode 100644 index 0000000000..0569e2ed86 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/10.sql @@ -0,0 +1,38 @@ +-- $ID$ +-- TPC-H/TPC-R Returned Item Reporting Query (Q10) +-- Functional Query Definition +-- Approved February 1998 + + +select + 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 >= date '1993-08-01' + and o_orderdate < date '1993-08-01' + interval '3' 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 +limit 20; diff --git a/test_runner/performance/tpc-h/queries/11.sql b/test_runner/performance/tpc-h/queries/11.sql new file mode 100644 index 0000000000..f7500c260e --- /dev/null +++ b/test_runner/performance/tpc-h/queries/11.sql @@ -0,0 +1,34 @@ +-- $ID$ +-- TPC-H/TPC-R Important Stock Identification Query (Q11) +-- Functional Query Definition +-- Approved February 1998 + + +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 = 'INDONESIA' +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 = 'INDONESIA' + ) +order by + value desc +; diff --git a/test_runner/performance/tpc-h/queries/12.sql b/test_runner/performance/tpc-h/queries/12.sql new file mode 100644 index 0000000000..bd879321c8 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/12.sql @@ -0,0 +1,35 @@ +-- $ID$ +-- TPC-H/TPC-R Shipping Modes and Order Priority Query (Q12) +-- Functional Query Definition +-- Approved February 1998 + + +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 ('REG AIR', 'AIR') + and l_commitdate < l_receiptdate + and l_shipdate < l_commitdate + and l_receiptdate >= date '1995-01-01' + and l_receiptdate < date '1995-01-01' + interval '1' year +group by + l_shipmode +order by + l_shipmode +; diff --git a/test_runner/performance/tpc-h/queries/13.sql b/test_runner/performance/tpc-h/queries/13.sql new file mode 100644 index 0000000000..554b2bec92 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/13.sql @@ -0,0 +1,27 @@ +-- $ID$ +-- TPC-H/TPC-R Customer Distribution Query (Q13) +-- Functional Query Definition +-- Approved February 1998 + + +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%accounts%' + group by + c_custkey + ) as c_orders (c_custkey, c_count) +group by + c_count +order by + custdist desc, + c_count desc +; diff --git a/test_runner/performance/tpc-h/queries/14.sql b/test_runner/performance/tpc-h/queries/14.sql new file mode 100644 index 0000000000..794a5656f5 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/14.sql @@ -0,0 +1,20 @@ +-- $ID$ +-- TPC-H/TPC-R Promotion Effect Query (Q14) +-- Functional Query Definition +-- Approved February 1998 + + +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 '1995-07-01' + and l_shipdate < date '1995-07-01' + interval '1' month +; diff --git a/test_runner/performance/tpc-h/queries/15.sql b/test_runner/performance/tpc-h/queries/15.sql new file mode 100644 index 0000000000..5d618c9906 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/15.sql @@ -0,0 +1,40 @@ +-- $ID$ +-- TPC-H/TPC-R Top Supplier Query (Q15) +-- Functional Query Definition +-- Approved February 1998 + +create view revenue0 (supplier_no, total_revenue) as + select + l_suppkey, + sum(l_extendedprice * (1 - l_discount)) + from + lineitem + where + l_shipdate >= date '1995-01-01' + and l_shipdate < date '1995-01-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 +; diff --git a/test_runner/performance/tpc-h/queries/16.sql b/test_runner/performance/tpc-h/queries/16.sql new file mode 100644 index 0000000000..f525d55d5d --- /dev/null +++ b/test_runner/performance/tpc-h/queries/16.sql @@ -0,0 +1,37 @@ +-- $ID$ +-- TPC-H/TPC-R Parts/Supplier Relationship Query (Q16) +-- Functional Query Definition +-- Approved February 1998 + + +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#43' + and p_type not like 'PROMO POLISHED%' + and p_size in (35, 5, 42, 13, 11, 40, 50, 47) + 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 +; diff --git a/test_runner/performance/tpc-h/queries/17.sql b/test_runner/performance/tpc-h/queries/17.sql new file mode 100644 index 0000000000..7d736cd3b5 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/17.sql @@ -0,0 +1,25 @@ + +-- $ID$ +-- TPC-H/TPC-R Small-Quantity-Order Revenue Query (Q17) +-- Functional Query Definition +-- Approved February 1998 + + +select + sum(l_extendedprice) / 7.0 as avg_yearly +from + lineitem, + part +where + p_partkey = l_partkey + and p_brand = 'Brand#35' + and p_container = 'JUMBO JAR' + and l_quantity < ( + select + 0.2 * avg(l_quantity) + from + lineitem + where + l_partkey = p_partkey + ) +; diff --git a/test_runner/performance/tpc-h/queries/18.sql b/test_runner/performance/tpc-h/queries/18.sql new file mode 100644 index 0000000000..13f7ce7306 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/18.sql @@ -0,0 +1,39 @@ +-- $ID$ +-- TPC-H/TPC-R Large Volume Customer Query (Q18) +-- Function Query Definition +-- Approved February 1998 + + +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) > 315 + ) + 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; diff --git a/test_runner/performance/tpc-h/queries/19.sql b/test_runner/performance/tpc-h/queries/19.sql new file mode 100644 index 0000000000..43a64bde6f --- /dev/null +++ b/test_runner/performance/tpc-h/queries/19.sql @@ -0,0 +1,42 @@ +-- $ID$ +-- TPC-H/TPC-R Discounted Revenue Query (Q19) +-- Functional Query Definition +-- Approved February 1998 + + +select + sum(l_extendedprice* (1 - l_discount)) as revenue +from + lineitem, + part +where + ( + p_partkey = l_partkey + and p_brand = 'Brand#41' + and p_container in ('SM CASE', 'SM BOX', 'SM PACK', 'SM PKG') + and l_quantity >= 10 and l_quantity <= 10 + 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#52' + and p_container in ('MED BAG', 'MED BOX', 'MED PKG', 'MED PACK') + and l_quantity >= 20 and l_quantity <= 20 + 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#14' + and p_container in ('LG CASE', 'LG BOX', 'LG PACK', 'LG PKG') + and l_quantity >= 22 and l_quantity <= 22 + 10 + and p_size between 1 and 15 + and l_shipmode in ('AIR', 'AIR REG') + and l_shipinstruct = 'DELIVER IN PERSON' + ) +; diff --git a/test_runner/performance/tpc-h/queries/2.sql b/test_runner/performance/tpc-h/queries/2.sql new file mode 100644 index 0000000000..2e8164b65a --- /dev/null +++ b/test_runner/performance/tpc-h/queries/2.sql @@ -0,0 +1,50 @@ +-- $ID$ +-- TPC-H/TPC-R Minimum Cost Supplier Query (Q2) +-- Functional Query Definition +-- Approved February 1998 + + +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 = 39 + and p_type like '%BRASS' + and s_nationkey = n_nationkey + and n_regionkey = r_regionkey + and r_name = 'MIDDLE EAST' + 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 = 'MIDDLE EAST' + ) +order by + s_acctbal desc, + n_name, + s_name, + p_partkey +limit 100; diff --git a/test_runner/performance/tpc-h/queries/20.sql b/test_runner/performance/tpc-h/queries/20.sql new file mode 100644 index 0000000000..7e587783c5 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/20.sql @@ -0,0 +1,44 @@ +-- $ID$ +-- TPC-H/TPC-R Potential Part Promotion Query (Q20) +-- Function Query Definition +-- Approved February 1998 + + +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 'bisque%' + ) + 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 '1997-01-01' + and l_shipdate < date '1997-01-01' + interval '1' year + ) + ) + and s_nationkey = n_nationkey + and n_name = 'ETHIOPIA' +order by + s_name +; diff --git a/test_runner/performance/tpc-h/queries/21.sql b/test_runner/performance/tpc-h/queries/21.sql new file mode 100644 index 0000000000..9a0a88236e --- /dev/null +++ b/test_runner/performance/tpc-h/queries/21.sql @@ -0,0 +1,46 @@ +-- $ID$ +-- TPC-H/TPC-R Suppliers Who Kept Orders Waiting Query (Q21) +-- Functional Query Definition +-- Approved February 1998 + + +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 = 'SAUDI ARABIA' +group by + s_name +order by + numwait desc, + s_name +limit 100; diff --git a/test_runner/performance/tpc-h/queries/22.sql b/test_runner/performance/tpc-h/queries/22.sql new file mode 100644 index 0000000000..965239f194 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/22.sql @@ -0,0 +1,44 @@ +-- $ID$ +-- TPC-H/TPC-R Global Sales Opportunity Query (Q22) +-- Functional Query Definition +-- Approved February 1998 + + +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 + ('15', '14', '29', '34', '33', '19', '13') + and c_acctbal > ( + select + avg(c_acctbal) + from + customer + where + c_acctbal > 0.00 + and substring(c_phone from 1 for 2) in + ('15', '14', '29', '34', '33', '19', '13') + ) + and not exists ( + select + * + from + orders + where + o_custkey = c_custkey + ) + ) as custsale +group by + cntrycode +order by + cntrycode +; diff --git a/test_runner/performance/tpc-h/queries/3.sql b/test_runner/performance/tpc-h/queries/3.sql new file mode 100644 index 0000000000..bbb8f7371a --- /dev/null +++ b/test_runner/performance/tpc-h/queries/3.sql @@ -0,0 +1,29 @@ +-- $ID$ +-- TPC-H/TPC-R Shipping Priority Query (Q3) +-- Functional Query Definition +-- Approved February 1998 + + +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-26' + and l_shipdate > date '1995-03-26' +group by + l_orderkey, + o_orderdate, + o_shippriority +order by + revenue desc, + o_orderdate +limit 10; diff --git a/test_runner/performance/tpc-h/queries/4.sql b/test_runner/performance/tpc-h/queries/4.sql new file mode 100644 index 0000000000..098b203414 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/4.sql @@ -0,0 +1,28 @@ +-- $ID$ +-- TPC-H/TPC-R Order Priority Checking Query (Q4) +-- Functional Query Definition +-- Approved February 1998 + + +select + o_orderpriority, + count(*) as order_count +from + orders +where + o_orderdate >= date '1996-12-01' + and o_orderdate < date '1996-12-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 +; diff --git a/test_runner/performance/tpc-h/queries/5.sql b/test_runner/performance/tpc-h/queries/5.sql new file mode 100644 index 0000000000..393e17987f --- /dev/null +++ b/test_runner/performance/tpc-h/queries/5.sql @@ -0,0 +1,31 @@ +-- $ID$ +-- TPC-H/TPC-R Local Supplier Volume Query (Q5) +-- Functional Query Definition +-- Approved February 1998 + + +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 >= date '1996-01-01' + and o_orderdate < date '1996-01-01' + interval '1' year +group by + n_name +order by + revenue desc +; diff --git a/test_runner/performance/tpc-h/queries/6.sql b/test_runner/performance/tpc-h/queries/6.sql new file mode 100644 index 0000000000..90ebcd4782 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/6.sql @@ -0,0 +1,16 @@ +-- $ID$ +-- TPC-H/TPC-R Forecasting Revenue Change Query (Q6) +-- Functional Query Definition +-- Approved February 1998 + + +select + sum(l_extendedprice * l_discount) as revenue +from + lineitem +where + l_shipdate >= date '1996-01-01' + and l_shipdate < date '1996-01-01' + interval '1' year + and l_discount between 0.02 - 0.01 and 0.02 + 0.01 + and l_quantity < 24 +; diff --git a/test_runner/performance/tpc-h/queries/7.sql b/test_runner/performance/tpc-h/queries/7.sql new file mode 100644 index 0000000000..8a34724b38 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/7.sql @@ -0,0 +1,46 @@ +-- $ID$ +-- TPC-H/TPC-R Volume Shipping Query (Q7) +-- Functional Query Definition +-- Approved February 1998 + + +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 = 'ALGERIA' and n2.n_name = 'CANADA') + or (n1.n_name = 'CANADA' and n2.n_name = 'ALGERIA') + ) + 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 +; diff --git a/test_runner/performance/tpc-h/queries/8.sql b/test_runner/performance/tpc-h/queries/8.sql new file mode 100644 index 0000000000..f8259c960b --- /dev/null +++ b/test_runner/performance/tpc-h/queries/8.sql @@ -0,0 +1,44 @@ +-- $ID$ +-- TPC-H/TPC-R National Market Share Query (Q8) +-- Functional Query Definition +-- Approved February 1998 + + +select + o_year, + sum(case + when nation = 'CANADA' 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 = 'AMERICA' + and s_nationkey = n2.n_nationkey + and o_orderdate between date '1995-01-01' and date '1996-12-31' + and p_type = 'SMALL POLISHED BRASS' + ) as all_nations +group by + o_year +order by + o_year +; diff --git a/test_runner/performance/tpc-h/queries/9.sql b/test_runner/performance/tpc-h/queries/9.sql new file mode 100644 index 0000000000..d2e2df9f00 --- /dev/null +++ b/test_runner/performance/tpc-h/queries/9.sql @@ -0,0 +1,39 @@ +-- $ID$ +-- TPC-H/TPC-R Product Type Profit Measure Query (Q9) +-- Functional Query Definition +-- Approved February 1998 + + +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 '%firebrick%' + ) as profit +group by + nation, + o_year +order by + nation, + o_year desc +;