From e6805369edcb4591cb29dccab0a3cfd5c51f6d3f Mon Sep 17 00:00:00 2001 From: Manan Gupta <35839558+GuptaManan100@users.noreply.github.com> Date: Thu, 18 Jul 2024 12:26:25 +0530 Subject: [PATCH] [release-18] Vitess tester workflow (#16127) (#16419) Signed-off-by: Manan Gupta Signed-off-by: Florent Poinsard <35779988+frouioui@users.noreply.github.com> Co-authored-by: Florent Poinsard <35779988+frouioui@users.noreply.github.com> --- .github/workflows/vitess_tester_vtgate.yml | 171 ++++ .../vtgate/vitess_tester/tpcc/tpcc.test | 210 +++++ .../vtgate/vitess_tester/tpch/tpch.test | 781 ++++++++++++++++++ test/ci_workflow_gen.go | 29 + test/templates/cluster_vitess_tester.tpl | 169 ++++ 5 files changed, 1360 insertions(+) create mode 100644 .github/workflows/vitess_tester_vtgate.yml create mode 100644 go/test/endtoend/vtgate/vitess_tester/tpcc/tpcc.test create mode 100644 go/test/endtoend/vtgate/vitess_tester/tpch/tpch.test create mode 100644 test/templates/cluster_vitess_tester.tpl diff --git a/.github/workflows/vitess_tester_vtgate.yml b/.github/workflows/vitess_tester_vtgate.yml new file mode 100644 index 00000000000..0c2965fee9c --- /dev/null +++ b/.github/workflows/vitess_tester_vtgate.yml @@ -0,0 +1,171 @@ +# DO NOT MODIFY: THIS FILE IS GENERATED USING "make generate_ci_workflows" + +name: Vitess Tester (vtgate) +on: [push, pull_request] +concurrency: + group: format('{0}-{1}', ${{ github.ref }}, 'Vitess Tester (vtgate)') + cancel-in-progress: true + +permissions: read-all + +env: + LAUNCHABLE_ORGANIZATION: "vitess" + LAUNCHABLE_WORKSPACE: "vitess-app" + GITHUB_PR_HEAD_SHA: "${{ github.event.pull_request.head.sha }}" + +jobs: + build: + name: Run endtoend tests on Vitess Tester (vtgate) + runs-on: gh-hosted-runners-4cores-1 + + steps: + - name: Skip CI + run: | + if [[ "${{contains( github.event.pull_request.labels.*.name, 'Skip CI')}}" == "true" ]]; then + echo "skipping CI due to the 'Skip CI' label" + exit 1 + fi + + - name: Check if workflow needs to be skipped + id: skip-workflow + run: | + skip='false' + if [[ "${{github.event.pull_request}}" == "" ]] && [[ "${{github.ref}}" != "refs/heads/main" ]] && [[ ! "${{github.ref}}" =~ ^refs/heads/release-[0-9]+\.[0-9]$ ]] && [[ ! "${{github.ref}}" =~ "refs/tags/.*" ]]; then + skip='true' + fi + echo Skip ${skip} + echo "skip-workflow=${skip}" >> $GITHUB_OUTPUT + + PR_DATA=$(curl -s\ + -H "Authorization: token ${{ secrets.GITHUB_TOKEN }}" \ + -H "Accept: application/vnd.github.v3+json" \ + "https://api.github.com/repos/${{ github.repository }}/pulls/${{ github.event.pull_request.number }}") + draft=$(echo "$PR_DATA" | jq .draft -r) + echo "is_draft=${draft}" >> $GITHUB_OUTPUT + + - name: Check out code + if: steps.skip-workflow.outputs.skip-workflow == 'false' + uses: actions/checkout@v4 + + - name: Check for changes in relevant files + if: steps.skip-workflow.outputs.skip-workflow == 'false' + uses: dorny/paths-filter@v3.0.1 + id: changes + with: + token: '' + filters: | + end_to_end: + - 'go/**/*.go' + - 'go/vt/sidecardb/**/*.sql' + - 'go/test/endtoend/onlineddl/vrepl_suite/**' + - 'test.go' + - 'Makefile' + - 'build.env' + - 'go.sum' + - 'go.mod' + - 'proto/*.proto' + - 'tools/**' + - 'config/**' + - 'bootstrap.sh' + - '.github/workflows/vitess_tester_vtgate.yml' + + - name: Set up Go + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + uses: actions/setup-go@v5 + with: + go-version: 1.22.5 + + - name: Set up python + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + uses: actions/setup-python@v5 + + - name: Tune the OS + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + run: | + # Limit local port range to not use ports that overlap with server side + # ports that we listen on. + sudo sysctl -w net.ipv4.ip_local_port_range="22768 65535" + # Increase the asynchronous non-blocking I/O. More information at https://dev.mysql.com/doc/refman/5.7/en/innodb-parameters.html#sysvar_innodb_use_native_aio + echo "fs.aio-max-nr = 1048576" | sudo tee -a /etc/sysctl.conf + sudo sysctl -p /etc/sysctl.conf + + - name: Get dependencies + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + run: | + # Get key to latest MySQL repo + sudo apt-key adv --keyserver keyserver.ubuntu.com --recv-keys A8D3785C + # Setup MySQL 8.0 + wget -c https://dev.mysql.com/get/mysql-apt-config_0.8.29-1_all.deb + echo mysql-apt-config mysql-apt-config/select-server select mysql-8.0 | sudo debconf-set-selections + sudo DEBIAN_FRONTEND="noninteractive" dpkg -i mysql-apt-config* + sudo apt-get -qq update + # Install everything else we need, and configure + sudo apt-get -qq install -y mysql-server mysql-client make unzip g++ etcd curl git wget eatmydata xz-utils libncurses5 + + sudo service mysql stop + sudo service etcd stop + sudo ln -s /etc/apparmor.d/usr.sbin.mysqld /etc/apparmor.d/disable/ + sudo apparmor_parser -R /etc/apparmor.d/usr.sbin.mysqld + go mod download + + # install JUnit report formatter + go install github.com/vitessio/go-junit-report@HEAD + + # install vitess tester + go install github.com/vitessio/vitess-tester@eb953122baba163ed8ccaa6642458ee984f5d7e4 + + - name: Setup launchable dependencies + if: steps.skip-workflow.outputs.is_draft == 'false' && steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' && github.base_ref == 'main' + run: | + # Get Launchable CLI installed. If you can, make it a part of the builder image to speed things up + pip3 install --user launchable~=1.0 > /dev/null + + # verify that launchable setup is all correct. + launchable verify || true + + # Tell Launchable about the build you are producing and testing + launchable record build --name "$GITHUB_RUN_ID" --no-commit-collection --source . + + - name: Run cluster endtoend test + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + timeout-minutes: 45 + run: | + # We set the VTDATAROOT to the /tmp folder to reduce the file path of mysql.sock file + # which musn't be more than 107 characters long. + export VTDATAROOT="/tmp/" + source build.env + make build + + set -exo pipefail + + i=1 + for dir in ./go/test/endtoend/vtgate/vitess_tester/*/; do + # We go over all the directories in the given path. + # If there is a vschema file there, we use it, otherwise we let vitess-tester autogenerate it. + if [ -f $dir/vschema.json ]; then + vitess-tester --sharded --xunit --test-dir $dir --vschema "$dir"vschema.json + else + vitess-tester --sharded --xunit --test-dir $dir + fi + # Number the reports by changing their file names. + mv report.xml report"$i".xml + i=$((i+1)) + done + + - name: Print test output and Record test result in launchable if PR is not a draft + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' && always() + run: | + if [[ "${{steps.skip-workflow.outputs.is_draft}}" == "false" ]]; then + # send recorded tests to launchable + launchable record tests --build "$GITHUB_RUN_ID" go-test . || true + fi + + # print test output + cat report*.xml + + - name: Test Summary + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' && always() + uses: test-summary/action@v2 + with: + paths: "report*.xml" + show: "fail, skip" diff --git a/go/test/endtoend/vtgate/vitess_tester/tpcc/tpcc.test b/go/test/endtoend/vtgate/vitess_tester/tpcc/tpcc.test new file mode 100644 index 00000000000..16f624aa1f6 --- /dev/null +++ b/go/test/endtoend/vtgate/vitess_tester/tpcc/tpcc.test @@ -0,0 +1,210 @@ +# The TPC-C Benchmark queries with some sample data so we can test the queries + +CREATE TABLE IF NOT EXISTS warehouse ( + w_id INT NOT NULL, + w_name VARCHAR(10), + w_street_1 VARCHAR(20), + w_street_2 VARCHAR(20), + w_city VARCHAR(20), + w_state CHAR(2), + w_zip CHAR(9), + w_tax DECIMAL(4, 4), + w_ytd DECIMAL(12, 2), + PRIMARY KEY (w_id) +); + +CREATE TABLE IF NOT EXISTS customer ( + c_id INT NOT NULL, + c_d_id INT NOT NULL, + c_w_id INT NOT NULL, + c_first VARCHAR(16), + c_middle CHAR(2), + c_last VARCHAR(16), + c_street_1 VARCHAR(20), + c_street_2 VARCHAR(20), + c_city VARCHAR(20), + c_state CHAR(2), + c_zip CHAR(9), + c_phone CHAR(16), + c_since DATETIME, + c_credit CHAR(2), + c_credit_lim DECIMAL(12, 2), + c_discount DECIMAL(4,4), + c_balance DECIMAL(12,2), + c_ytd_payment DECIMAL(12,2), + c_payment_cnt INT, + c_delivery_cnt INT, + c_data VARCHAR(500), + PRIMARY KEY(c_w_id, c_d_id, c_id), + INDEX idx_customer (c_w_id, c_d_id, c_last, c_first) +); + +CREATE TABLE IF NOT EXISTS district ( + d_id INT NOT NULL, + d_w_id INT NOT NULL, + d_name VARCHAR(10), + d_street_1 VARCHAR(20), + d_street_2 VARCHAR(20), + d_city VARCHAR(20), + d_state CHAR(2), + d_zip CHAR(9), + d_tax DECIMAL(4, 4), + d_ytd DECIMAL(12, 2), + d_next_o_id INT, + PRIMARY KEY (d_w_id, d_id) +); + +CREATE TABLE IF NOT EXISTS history ( + h_c_id INT NOT NULL, + h_c_d_id INT NOT NULL, + h_c_w_id INT NOT NULL, + h_d_id INT NOT NULL, + h_w_id INT NOT NULL, + h_date DATETIME, + h_amount DECIMAL(6, 2), + h_data VARCHAR(24), + INDEX idx_h_w_id (h_w_id), + INDEX idx_h_c_w_id (h_c_w_id) +); + +CREATE TABLE IF NOT EXISTS new_orders ( + no_o_id INT NOT NULL, + no_d_id INT NOT NULL, + no_w_id INT NOT NULL, + PRIMARY KEY(no_w_id, no_d_id, no_o_id) +); + +CREATE TABLE IF NOT EXISTS orders ( + o_id INT NOT NULL, + o_d_id INT NOT NULL, + o_w_id INT NOT NULL, + o_c_id INT, + o_entry_d DATETIME, + o_carrier_id INT, + o_ol_cnt INT, + o_all_local INT, + PRIMARY KEY(o_w_id, o_d_id, o_id), + INDEX idx_order (o_w_id, o_d_id, o_c_id, o_id) +); + +CREATE TABLE IF NOT EXISTS order_line ( + ol_o_id INT NOT NULL, + ol_d_id INT NOT NULL, + ol_w_id INT NOT NULL, + ol_number INT NOT NULL, + ol_i_id INT NOT NULL, + ol_supply_w_id INT, + ol_delivery_d DATETIME, + ol_quantity INT, + ol_amount DECIMAL(6, 2), + ol_dist_info CHAR(24), + PRIMARY KEY(ol_w_id, ol_d_id, ol_o_id, ol_number) +); + +CREATE TABLE IF NOT EXISTS stock ( + s_i_id INT NOT NULL, + s_w_id INT NOT NULL, + s_quantity INT, + s_dist_01 CHAR(24), + s_dist_02 CHAR(24), + s_dist_03 CHAR(24), + s_dist_04 CHAR(24), + s_dist_05 CHAR(24), + s_dist_06 CHAR(24), + s_dist_07 CHAR(24), + s_dist_08 CHAR(24), + s_dist_09 CHAR(24), + s_dist_10 CHAR(24), + s_ytd INT, + s_order_cnt INT, + s_remote_cnt INT, + s_data VARCHAR(50), + PRIMARY KEY(s_w_id, s_i_id) +); + +CREATE TABLE IF NOT EXISTS item ( + i_id INT NOT NULL, + i_im_id INT, + i_name VARCHAR(24), + i_price DECIMAL(5, 2), + i_data VARCHAR(50), + PRIMARY KEY(i_id) +); + +INSERT INTO warehouse (w_id, w_name, w_street_1, w_street_2, w_city, w_state, w_zip, w_tax, w_ytd) VALUES +(1, 'Main', '123 Elm St', 'Suite 100', 'Anytown', 'CA', '12345', 0.0750, 100000.00), +(2, 'Side', '123 Storgatan', 'Suite 666', 'Uptown', 'SE', '87654', 0.0150, 200000.00); + +INSERT INTO customer (c_id, c_d_id, c_w_id, c_first, c_middle, c_last, c_street_1, c_street_2, c_city, c_state, c_zip, c_phone, c_since, c_credit, c_credit_lim, c_discount, c_balance, c_ytd_payment, c_payment_cnt, c_delivery_cnt, c_data) VALUES +(10, 15, 1, 'John', 'Q', 'Public', '456 Oak St', 'Apt 5', 'Othertown', 'NY', '54321', '555-1234-5678', '2023-01-01 12:00:00', 'Y', 50000.00, 0.0500, -100.00, 1500.00, 15, 2, 'Frequent shopper'), +(1, 1, 5, 'Jane', 'R', 'last', '789 Pine St', 'Unit 7', 'Smalltown', 'TX', '98765', '555-8765-4321', '2023-02-02 14:30:00', 'N', 75000.00, 0.0250, 500.00, 250.00, 5, 1, 'Occasional shopper'), +(2, 1, 5, 'Jake', 'S', 'last', '101 Birch St', 'Suite 21', 'Middletown', 'FL', '32145', '555-5678-1234', '2023-03-03 16:45:00', 'Y', 100000.00, 0.1000, 200.00, 300.00, 10, 3, 'Regular shopper'), +(3, 5, 8, 'Alice', 'T', 'item_last', '102 Acacia Ave', 'Top Floor', 'Bigtown', 'CO', '12345', '555-9876-5432', '2023-04-04 18:00:00', 'N', 30000.00, 0.0750, 150.00, 100.00, 3, 1, 'Sporadic shopper'), +(4, 5, 8, 'Bob', 'U', 'item_last', '103 Maple Dr', 'Room 6', 'Laketown', 'WA', '98765', '555-6543-2109', '2023-05-05 19:15:00', 'Y', 20000.00, 0.0500, 0.00, 50.00, 2, 0, 'New shopper'), +(9, 1, 8965, 'Charlie', 'V', 'Quiet', '104 Cedar Ln', 'Basement', 'Cloudtown', 'VT', '54321', '555-3210-9876', '2023-06-06 20:30:00', 'N', 15000.00, 0.0200, 75.00, 25.00, 1, 0, 'Rare shopper'), +(5, 68, 32, 'Dan', 'W', 'Anyone', '105 Spruce Rd', 'Floor 2', 'Hilltown', 'ME', '32145', '555-4321-0987', '2023-07-07 21:45:00', 'Y', 10000.00, 0.0150, 500.00, 75.00, 5, 2, 'Ad hoc shopper'); + +INSERT INTO district (d_id, d_w_id, d_name, d_street_1, d_street_2, d_city, d_state, d_zip, d_tax, d_ytd, d_next_o_id) VALUES +(95, 15, 'Central', '123 Central St', 'Unit 5', 'Centerville', 'CA', '95021', 0.0850, 20000.00, 10), +(9, 896, 'Eastside', '789 East St', 'Bldg 2', 'Eastville', 'NY', '10021', 0.0750, 15000.00, 20), +(6, 21, 'Westend', '456 West Rd', 'Suite 8', 'Westtown', 'TX', '77019', 0.0650, 50000.00, 30); + +INSERT INTO orders (o_id, o_d_id, o_w_id, o_c_id, o_entry_d, o_carrier_id, o_ol_cnt, o_all_local) VALUES +(10, 3, 9894, 159, '2024-04-30 12:00:00', 12, 5, 1), +(9, 3, 9894, 159, '2024-04-29 12:00:00', 15, 3, 1), +(8, 3, 9894, 159, '2024-04-28 12:00:00', null, 4, 1), +(6, 1983, 894605, 204, '2024-04-27 12:00:00', 10, 2, 0), +(2110, 1, 1, 105, '2024-04-15 10:00:00', 5, 3, 1), +(3000, 1, 1, 105, '2024-04-16 10:05:00', 6, 2, 1), +(4200, 1, 1, 105, '2024-04-17 10:10:00', 7, 1, 1); + +INSERT INTO order_line (ol_o_id, ol_d_id, ol_w_id, ol_number, ol_i_id, ol_supply_w_id, ol_delivery_d, ol_quantity, ol_amount, ol_dist_info) VALUES + (1, 5, 92, 1, 101, 92, '2024-05-01 12:00:00', 5, 150.00, 'xyzabcdefghijklmnopr'), + (680, 201, 87, 1, 102, 87, '2024-05-02 13:00:00', 10, 100.00, 'yzabcdefghijklmnopqr'), + (680, 201, 87, 2, 103, 87, '2024-05-02 13:05:00', 2, 50.00, 'zabcdefghijklmnopqrs'), + (45, 156, 1, 1, 104, 1, '2024-05-03 14:00:00', 20, 200.00, 'abcdejklmnopqrsvwxyx'), + (56, 156, 1, 2, 105, 1, '2024-05-04 15:00:00', 30, 250.00, 'bcdefghiqrstuvwxyza'), + (15, 1908, 12, 1, 106, 12, '2024-05-05 16:00:00', 3, 75.00, 'cdefghijklmnopqwxyzab'); + +INSERT INTO stock (s_i_id, s_w_id, s_quantity, s_dist_01, s_dist_02, s_dist_03, s_dist_04, s_dist_05, s_dist_06, s_dist_07, s_dist_08, s_dist_09, s_dist_10, s_ytd, s_order_cnt, s_remote_cnt, s_data) VALUES +(101, 92, 50, 'distdata1', 'distdata2', 'distdata3', 'distdata4', 'distdata5', 'distdata6', 'distdata7', 'distdata8', 'distdata9', 'distdata10', 1000, 100, 10, 'Example data string'), +(102, 87, 30, 'distdata1', 'distdata2', 'distdata3', 'distdata4', 'distdata5', 'distdata6', 'distdata7', 'distdata8', 'distdata9', 'distdata10', 500, 50, 5, 'Another example string'), +(106, 12, 5, 'distdata1', 'distdata2', 'distdata3', 'distdata4', 'distdata5', 'distdata6', 'distdata7', 'distdata8', 'distdata9', 'distdata10', 300, 30, 3, 'Yet another string'), +(8, 1, 900, 'distdata1', 'distdata2', 'distdata3', 'distdata4', 'distdata5', 'distdata6', 'distdata7', 'distdata8', 'distdata9', 'distdata10', 800, 80, 8, 'Low stock string'), +(2198, 89, 100, 'distdata1', '', '', '', '', '', '', '', '', '', 150, 15, 1, 'Critical stock data'); + +INSERT INTO new_orders (no_o_id, no_d_id, no_w_id) VALUES +(10, 689, 15), +(11, 689, 15), +(12, 689, 15); + +INSERT INTO item (i_id, i_im_id, i_name, i_price, i_data) VALUES +(9654, 123, 'Gadget', 199.99, 'High-quality electronic gadget'), +(9655, 124, 'Widget', 29.99, 'Durable plastic widget'); + +# Here follows the SELECT queries we are testing. +# The TPCC benchmark also uses INSERT, UPDATE and DELETE queries, but we are not testing those here. +-- wait_authoritative customer +-- wait_authoritative warehouse +SELECT c_discount, c_last, c_credit, w_tax FROM customer AS c JOIN warehouse AS w ON c_w_id=w_id WHERE w_id = 1 AND c_d_id = 15 AND c_id = 10; +SELECT count(c_id) namecnt FROM customer WHERE c_w_id = 5 AND c_d_id= 1 AND c_last='last'; +SELECT c_id FROM customer WHERE c_w_id = 8 AND c_d_id = 5 AND c_last='item_last' ORDER BY c_first; +SELECT c_first, c_middle, c_last, c_street_1, c_street_2, c_city, c_state, c_zip, c_phone, c_credit, c_credit_lim, c_discount, c_balance, c_ytd_payment, c_since FROM customer WHERE c_w_id = 8965 AND c_d_id = 1 AND c_id = 9; +SELECT c_data FROM customer WHERE c_w_id = 32 AND c_d_id=68 AND c_id = 5; +SELECT count(c_id) namecnt FROM customer WHERE c_w_id = 870 AND c_d_id= 780 AND c_last='last'; +SELECT c_balance, c_first, c_middle, c_id FROM customer WHERE c_w_id = 840 AND c_d_id= 1 AND c_last='test' ORDER BY c_first; +SELECT c_balance, c_first, c_middle, c_last FROM customer WHERE c_w_id = 15 AND c_d_id=5169 AND c_id=1; +SELECT d_next_o_id, d_tax FROM district WHERE d_w_id = 15 AND d_id = 95; +SELECT d_street_1, d_street_2, d_city, d_state, d_zip, d_name FROM district WHERE d_w_id = 896 AND d_id = 9; +SELECT d_next_o_id FROM district WHERE d_id = 6 AND d_w_id= 21; +SELECT o_id, o_carrier_id, o_entry_d FROM orders WHERE o_w_id = 9894 AND o_d_id = 3 AND o_c_id = 159 ORDER BY o_id DESC; +SELECT o_c_id FROM orders WHERE o_id = 6 AND o_d_id = 1983 AND o_w_id = 894605; +SELECT ol_i_id, ol_supply_w_id, ol_quantity, ol_amount, ol_delivery_d FROM order_line WHERE ol_w_id = 92 AND ol_d_id = 5 AND ol_o_id = 1; +SELECT SUM(ol_amount) sm FROM order_line WHERE ol_o_id = 680 AND ol_d_id = 201 AND ol_w_id = 87; +SELECT DISTINCT ol_i_id FROM order_line WHERE ol_w_id = 1 AND ol_d_id = 156 AND ol_o_id < 500 AND ol_o_id >= 56; +SELECT COUNT(DISTINCT(s.s_i_id)) FROM stock AS s JOIN order_line AS ol ON ol.ol_w_id=s.s_w_id AND ol.ol_i_id=s.s_i_id WHERE ol.ol_w_id = 12 AND ol.ol_d_id = 1908 AND ol.ol_o_id < 30 AND ol.ol_o_id >= 15 AND s.s_w_id= 12 AND s.s_quantity < 10; +SELECT count(*) FROM stock WHERE s_w_id = 1 AND s_i_id = 8 AND s_quantity < 1000; +SELECT s_quantity, s_data, s_dist_01 s_dist FROM stock WHERE s_i_id = 2198 AND s_w_id = 89; +SELECT no_o_id FROM new_orders WHERE no_d_id = 689 AND no_w_id = 15 ORDER BY no_o_id ASC LIMIT 1; +SELECT i_price, i_name, i_data FROM item WHERE i_id = 9654; +SELECT w_street_1, w_street_2, w_city, w_state, w_zip, w_name FROM warehouse WHERE w_id = 998; \ No newline at end of file diff --git a/go/test/endtoend/vtgate/vitess_tester/tpch/tpch.test b/go/test/endtoend/vtgate/vitess_tester/tpch/tpch.test new file mode 100644 index 00000000000..f2cb025a7b3 --- /dev/null +++ b/go/test/endtoend/vtgate/vitess_tester/tpch/tpch.test @@ -0,0 +1,781 @@ +# http://www.tpc.org/tpc_documents_current_versions/pdf/tpc-h_v2.17.1.pdf + +CREATE TABLE IF NOT EXISTS nation ( N_NATIONKEY INTEGER NOT NULL, + N_NAME CHAR(25) NOT NULL, + N_REGIONKEY INTEGER NOT NULL, + N_COMMENT VARCHAR(152), + PRIMARY KEY (N_NATIONKEY)); + +CREATE TABLE IF NOT EXISTS region ( R_REGIONKEY INTEGER NOT NULL, + R_NAME CHAR(25) NOT NULL, + R_COMMENT VARCHAR(152), + PRIMARY KEY (R_REGIONKEY)); + +CREATE TABLE IF NOT EXISTS 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, + PRIMARY KEY (P_PARTKEY)); + +CREATE TABLE IF NOT EXISTS 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, + PRIMARY KEY (S_SUPPKEY)); + +CREATE TABLE IF NOT EXISTS 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, + PRIMARY KEY (PS_PARTKEY,PS_SUPPKEY)); + +CREATE TABLE IF NOT EXISTS 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, + PRIMARY KEY (C_CUSTKEY)); + +CREATE TABLE IF NOT EXISTS 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, + PRIMARY KEY (O_ORDERKEY)); + +CREATE TABLE IF NOT EXISTS 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, + PRIMARY KEY (L_ORDERKEY,L_LINENUMBER)); + +INSERT INTO region (R_REGIONKEY, R_NAME, R_COMMENT) VALUES + (1, 'ASIA', 'Eastern Asia'), + (2, 'MIDDLE EAST', 'Rich cultural heritage'); + +INSERT INTO nation (N_NATIONKEY, N_NAME, N_REGIONKEY, N_COMMENT) VALUES + (1, 'China', 1, 'Large population'), + (2, 'India', 1, 'Large variety of cultures'), + (3, 'Nation A', 2, 'Historic sites'), + (4, 'Nation B', 2, 'Beautiful landscapes'); + +INSERT INTO supplier (S_SUPPKEY, S_NAME, S_ADDRESS, S_NATIONKEY, S_PHONE, S_ACCTBAL, S_COMMENT) VALUES + (1, 'Supplier A', '123 Square', 1, '86-123-4567', 5000.00, 'High quality steel'), + (2, 'Supplier B', '456 Ganges St', 2, '91-789-4561', 5500.00, 'Efficient production'), + (3, 'Supplier 1', 'Supplier Address 1', 3, '91-789-4562', 3000.00, 'Supplier Comment 1'), + (4, 'Supplier 2', 'Supplier Address 2', 2, '91-789-4563', 4000.00, 'Supplier Comment 2'); + +INSERT INTO part (P_PARTKEY, P_NAME, P_MFGR, P_BRAND, P_TYPE, P_SIZE, P_CONTAINER, P_RETAILPRICE, P_COMMENT) VALUES + (100, 'Part 100', 'MFGR A', 'Brand X', 'BOLT STEEL', 30, 'SM BOX', 45.00, 'High strength'), + (101, 'Part 101', 'MFGR B', 'Brand Y', 'NUT STEEL', 30, 'LG BOX', 30.00, 'Rust resistant'); + +INSERT INTO partsupp (PS_PARTKEY, PS_SUPPKEY, PS_AVAILQTY, PS_SUPPLYCOST, PS_COMMENT) VALUES + (100, 1, 500, 10.00, 'Deliveries on time'), + (101, 2, 300, 9.00, 'Back orders possible'), + (100, 2, 600, 8.50, 'Bulk discounts available'); + +INSERT INTO customer (C_CUSTKEY, C_NAME, C_ADDRESS, C_NATIONKEY, C_PHONE, C_ACCTBAL, C_MKTSEGMENT, C_COMMENT) VALUES + (1, 'Customer A', '1234 Drive Lane', 1, '123-456-7890', 1000.00, 'AUTOMOBILE', 'Frequent orders'), + (2, 'Customer B', '5678 Park Ave', 2, '234-567-8901', 2000.00, 'AUTOMOBILE', 'Large orders'), + (3, 'Customer 1', 'Address 1', 1, 'Phone 1', 1000.00, 'Segment 1', 'Comment 1'), + (4, 'Customer 2', 'Address 2', 2, 'Phone 2', 2000.00, 'Segment 2', 'Comment 2'); + +INSERT INTO orders (O_ORDERKEY, O_CUSTKEY, O_ORDERSTATUS, O_TOTALPRICE, O_ORDERDATE, O_ORDERPRIORITY, O_CLERK, O_SHIPPRIORITY, O_COMMENT) VALUES + (100, 1, 'O', 15000.00, '1995-03-10', '1-URGENT', 'Clerk#0001', 1, 'N/A'), + (101, 2, 'O', 25000.00, '1995-03-05', '2-HIGH', 'Clerk#0002', 2, 'N/A'), + (1, 3, 'O', 10000.00, '1994-01-10', 'Priority 1', 'Clerk 1', 1, 'Order Comment 1'), + (2, 4, 'O', 20000.00, '1994-06-15', 'Priority 2', 'Clerk 2', 1, 'Order Comment 2'); + +INSERT INTO lineitem (L_ORDERKEY, L_PARTKEY, L_SUPPKEY, L_LINENUMBER, L_QUANTITY, L_EXTENDEDPRICE, L_DISCOUNT, L_TAX, L_RETURNFLAG, L_LINESTATUS, L_SHIPDATE, L_COMMITDATE, L_RECEIPTDATE, L_SHIPINSTRUCT, L_SHIPMODE, L_COMMENT) VALUES + (100, 200, 300, 1, 10, 5000.00, 0.05, 0.10, 'N', 'O', '1995-03-15', '1995-03-14', '1995-03-16', 'DELIVER IN PERSON', 'TRUCK', 'Urgent delivery'), + (100, 201, 301, 2, 20, 10000.00, 0.10, 0.10, 'R', 'F', '1995-03-17', '1995-03-15', '1995-03-18', 'NONE', 'MAIL', 'Handle with care'), + (101, 202, 302, 1, 30, 15000.00, 0.00, 0.10, 'A', 'F', '1995-03-20', '1995-03-18', '1995-03-21', 'TAKE BACK RETURN', 'SHIP', 'Standard delivery'), + (101, 203, 303, 2, 40, 10000.00, 0.20, 0.10, 'N', 'O', '1995-03-22', '1995-03-20', '1995-03-23', 'DELIVER IN PERSON', 'RAIL', 'Expedite'), + (1, 101, 1, 1, 5, 5000.00, 0.1, 0.05, 'N', 'O', '1994-01-12', '1994-01-11', '1994-01-13', 'Deliver in person','TRUCK', 'Lineitem Comment 1'), + (2, 102, 2, 1, 3, 15000.00, 0.2, 0.05, 'R', 'F', '1994-06-17', '1994-06-15', '1994-06-18', 'Leave at front door','AIR', 'Lineitem Comment 2'), + (11, 100, 2, 1, 30, 10000.00, 0.05, 0.07, 'A', 'F', '1998-07-21', '1998-07-22', '1998-07-23', 'DELIVER IN PERSON', 'TRUCK', 'N/A'), + (12, 101, 3, 1, 50, 15000.00, 0.10, 0.08, 'N', 'O', '1998-08-10', '1998-08-11', '1998-08-12', 'NONE', 'AIR', 'N/A'), + (13, 102, 4, 1, 70, 21000.00, 0.02, 0.04, 'R', 'F', '1998-06-30', '1998-07-01', '1998-07-02', 'TAKE BACK RETURN', 'MAIL', 'N/A'), + (14, 103, 5, 1, 90, 30000.00, 0.15, 0.10, 'A', 'O', '1998-05-15', '1998-05-16', '1998-05-17', 'DELIVER IN PERSON', 'RAIL', 'N/A'), + (15, 104, 2, 1, 45, 45000.00, 0.20, 0.15, 'N', 'F', '1998-07-15', '1998-07-16', '1998-07-17', 'NONE', 'SHIP', 'N/A'); + +# Query 1 +-- skip +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_sub('1998-12-01', interval 108 day) +group by + l_returnflag, + l_linestatus +order by + l_returnflag, + l_linestatus; + +# Query 2 +-- skip +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 = 30 + and p_type like '%STEEL' + and s_nationkey = n_nationkey + and n_regionkey = r_regionkey + and r_name = 'ASIA' + 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 = 'ASIA' + ) +order by + s_acctbal desc, + n_name, + s_name, + p_partkey +limit 100; + +-- wait_authoritative customer +-- wait_authoritative orders +-- wait_authoritative lineitem +# Q3 Shipping Priority Query +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 < '1995-03-13' + and l_shipdate > '1995-03-13' +group by + l_orderkey, + o_orderdate, + o_shippriority +order by + revenue desc, + o_orderdate +limit 10; + +# Q4 Order Priority Checking Query +select + o_orderpriority, + count(*) as order_count +from + orders +where + o_orderdate >= '1995-01-01' + and o_orderdate < date_add('1995-01-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; + +# Q5 Local Supplier Volume Query +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 = 'MIDDLE EAST' + and o_orderdate >= '1994-01-01' + and o_orderdate < date_add('1994-01-01', interval '1' year) +group by + n_name +order by + revenue desc; + +# Q6 Forecasting Revenue Change Query +select + sum(l_extendedprice * l_discount) as revenue +from + lineitem +where + l_shipdate >= '1994-01-01' + and l_shipdate < date_add('1994-01-01', interval '1' year) + and l_discount between 0.06 - 0.01 and 0.06 + 0.01 + and l_quantity < 24; + +# Q7 Volume Shipping Query +-- skip +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 = 'JAPAN' and n2.n_name = 'INDIA') + or (n1.n_name = 'INDIA' and n2.n_name = 'JAPAN') + ) + and l_shipdate between '1995-01-01' and '1996-12-31' + ) as shipping +group by + supp_nation, + cust_nation, + l_year +order by + supp_nation, + cust_nation, + l_year; + +# Q8 National Market Share Query +-- skip +select + o_year, + sum(case + when nation = 'INDIA' 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 = 'ASIA' + and s_nationkey = n2.n_nationkey + and o_orderdate between '1995-01-01' and '1996-12-31' + and p_type = 'SMALL PLATED COPPER' + ) as all_nations +group by + o_year +order by + o_year; + +# Q9 Product Type Profit Measure Query +-- skip +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 '%dim%' + ) as profit +group by + nation, + o_year +order by + nation, + o_year desc; + +# Q10 Returned Item Reporting Query +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 >= '1993-08-01' + and o_orderdate < date_add('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; + +# Q11 Important Stock Identification Query +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 = 'MOZAMBIQUE' +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 = 'MOZAMBIQUE' + ) +order by + value desc; + +# Q12 Shipping Modes and Order Priority Query +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 ('RAIL', 'FOB') + and l_commitdate < l_receiptdate + and l_shipdate < l_commitdate + and l_receiptdate >= '1997-01-01' + and l_receiptdate < date_add('1997-01-01', interval '1' year) +group by + l_shipmode +order by + l_shipmode; + +# Q13 Customer Distribution Query +select + c_count, + count(*) as custdist +from + ( + select + c_custkey, + count(o_orderkey) as c_count + from + customer left outer join orders on + c_custkey = o_custkey + and o_comment not like '%pending%deposits%' + group by + c_custkey + ) c_orders +group by + c_count +order by + custdist desc, + c_count desc; + +# Q14 Promotion Effect Query +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 >= '1996-12-01' + and l_shipdate < date_add('1996-12-01', interval '1' month); + +# Q16 Parts/Supplier Relationship Query +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#34' + and p_type not like 'LARGE BRUSHED%' + and p_size in (48, 19, 12, 4, 41, 7, 21, 39) + 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; + +# Q17 Small-Quantity-Order Revenue Query +--skip correlated subquery is only supported for EXISTS +select + sum(l_extendedprice) / 7.0 as avg_yearly +from + lineitem, + part +where + p_partkey = l_partkey + and p_brand = 'Brand#44' + and p_container = 'WRAP PKG' + and l_quantity < ( + select + 0.2 * avg(l_quantity) + from + lineitem + where + l_partkey = p_partkey + ); + +# Q18 Large Volume Customer Query +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) > 314 + ) + 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; + +# Q19 Discounted Revenue Query +select + sum(l_extendedprice* (1 - l_discount)) as revenue +from + lineitem, + part +where + ( + p_partkey = l_partkey + and p_brand = 'Brand#52' + and p_container in ('SM CASE', 'SM BOX', 'SM PACK', 'SM PKG') + and l_quantity >= 4 and l_quantity <= 4 + 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#11' + and p_container in ('MED BAG', 'MED BOX', 'MED PKG', 'MED PACK') + and l_quantity >= 18 and l_quantity <= 18 + 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#51' + and p_container in ('LG CASE', 'LG BOX', 'LG PACK', 'LG PKG') + and l_quantity >= 29 and l_quantity <= 29 + 10 + and p_size between 1 and 15 + and l_shipmode in ('AIR', 'AIR REG') + and l_shipinstruct = 'DELIVER IN PERSON' + ); + +# Q20 Potential Part Promotion Query +--skip correlated subquery is only supported for EXISTS +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 'green%' + ) + and ps_availqty > ( + select + 0.5 * sum(l_quantity) + from + lineitem + where + l_partkey = ps_partkey + and l_suppkey = ps_suppkey + and l_shipdate >= '1993-01-01' + and l_shipdate < date_add('1993-01-01', interval '1' year) + ) + ) + and s_nationkey = n_nationkey + and n_name = 'ALGERIA' +order by + s_name; + + +# Q21 Suppliers Who Kept Orders Waiting Query +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 = 'EGYPT' +group by + s_name +order by + numwait desc, + s_name +limit 100; + +# Q22 Global Sales Opportunity Query +-- skip correlated subquery is only supported for EXISTS +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 + ('20', '40', '22', '30', '39', '42', '21') + and c_acctbal > ( + select + avg(c_acctbal) + from + customer + where + c_acctbal > 0.00 + and substring(c_phone from 1 for 2) in + ('20', '40', '22', '30', '39', '42', '21') + ) + and not exists ( + select + * + from + orders + where + o_custkey = c_custkey + ) + ) as custsale +group by + cntrycode +order by + cntrycode; \ No newline at end of file diff --git a/test/ci_workflow_gen.go b/test/ci_workflow_gen.go index 5a3031d7307..a188411e34e 100644 --- a/test/ci_workflow_gen.go +++ b/test/ci_workflow_gen.go @@ -60,6 +60,7 @@ const ( dockerFileTemplate = "templates/dockerfile.tpl" clusterTestSelfHostedTemplate = "templates/cluster_endtoend_test_self_hosted.tpl" clusterTestDockerTemplate = "templates/cluster_endtoend_test_docker.tpl" + clusterVitessTesterTemplate = "templates/cluster_vitess_tester.tpl" ) var ( @@ -128,6 +129,10 @@ var ( "vttablet_prscomplex", } + vitessTesterMap = map[string]string{ + "vtgate": "./go/test/endtoend/vtgate/vitess_tester", + } + clusterSelfHostedList = []string{} clusterDockerList = []string{} clustersRequiringXtraBackup = []string{ @@ -172,6 +177,12 @@ type selfHostedTest struct { MakeTools, InstallXtraBackup, Docker bool } +type vitessTesterTest struct { + FileName string + Name string + Path string +} + // clusterMySQLVersions return list of mysql versions (one or more) that this cluster needs to test against func clusterMySQLVersions(clusterName string) mysqlVersions { switch { @@ -217,6 +228,7 @@ func mergeBlankLines(buf *bytes.Buffer) string { func main() { generateUnitTestWorkflows() + generateVitessTesterWorkflows(vitessTesterMap, clusterVitessTesterTemplate) generateClusterWorkflows(clusterList, clusterTestTemplate) generateClusterWorkflows(clusterDockerList, clusterTestDockerTemplate) @@ -333,6 +345,23 @@ func generateSelfHostedClusterWorkflows() error { return nil } +func generateVitessTesterWorkflows(mp map[string]string, tpl string) { + for test, testPath := range mp { + tt := &vitessTesterTest{ + Name: fmt.Sprintf("Vitess Tester (%v)", test), + Path: testPath, + } + + templateFileName := tpl + tt.FileName = fmt.Sprintf("vitess_tester_%s.yml", test) + workflowPath := fmt.Sprintf("%s/%s", workflowConfigDir, tt.FileName) + err := writeFileFromTemplate(templateFileName, workflowPath, tt) + if err != nil { + log.Print(err) + } + } +} + func generateClusterWorkflows(list []string, tpl string) { clusters := canonnizeList(list) for _, cluster := range clusters { diff --git a/test/templates/cluster_vitess_tester.tpl b/test/templates/cluster_vitess_tester.tpl new file mode 100644 index 00000000000..bd34c2de088 --- /dev/null +++ b/test/templates/cluster_vitess_tester.tpl @@ -0,0 +1,169 @@ +name: {{.Name}} +on: [push, pull_request] +concurrency: + group: format('{0}-{1}', ${{"{{"}} github.ref {{"}}"}}, '{{.Name}}') + cancel-in-progress: true + +permissions: read-all + +env: + LAUNCHABLE_ORGANIZATION: "vitess" + LAUNCHABLE_WORKSPACE: "vitess-app" + GITHUB_PR_HEAD_SHA: "${{`{{ github.event.pull_request.head.sha }}`}}" + +jobs: + build: + name: Run endtoend tests on {{.Name}} + runs-on: gh-hosted-runners-4cores-1 + + steps: + - name: Skip CI + run: | + if [[ "{{"${{contains( github.event.pull_request.labels.*.name, 'Skip CI')}}"}}" == "true" ]]; then + echo "skipping CI due to the 'Skip CI' label" + exit 1 + fi + + - name: Check if workflow needs to be skipped + id: skip-workflow + run: | + skip='false' + if [[ "{{"${{github.event.pull_request}}"}}" == "" ]] && [[ "{{"${{github.ref}}"}}" != "refs/heads/main" ]] && [[ ! "{{"${{github.ref}}"}}" =~ ^refs/heads/release-[0-9]+\.[0-9]$ ]] && [[ ! "{{"${{github.ref}}"}}" =~ "refs/tags/.*" ]]; then + skip='true' + fi + echo Skip ${skip} + echo "skip-workflow=${skip}" >> $GITHUB_OUTPUT + + PR_DATA=$(curl -s\ + -H "{{"Authorization: token ${{ secrets.GITHUB_TOKEN }}"}}" \ + -H "Accept: application/vnd.github.v3+json" \ + "{{"https://api.github.com/repos/${{ github.repository }}/pulls/${{ github.event.pull_request.number }}"}}") + draft=$(echo "$PR_DATA" | jq .draft -r) + echo "is_draft=${draft}" >> $GITHUB_OUTPUT + + - name: Check out code + if: steps.skip-workflow.outputs.skip-workflow == 'false' + uses: actions/checkout@v4 + + - name: Check for changes in relevant files + if: steps.skip-workflow.outputs.skip-workflow == 'false' + uses: dorny/paths-filter@v3.0.1 + id: changes + with: + token: '' + filters: | + end_to_end: + - 'go/**/*.go' + - 'go/vt/sidecardb/**/*.sql' + - 'go/test/endtoend/onlineddl/vrepl_suite/**' + - 'test.go' + - 'Makefile' + - 'build.env' + - 'go.sum' + - 'go.mod' + - 'proto/*.proto' + - 'tools/**' + - 'config/**' + - 'bootstrap.sh' + - '.github/workflows/{{.FileName}}' + + - name: Set up Go + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + uses: actions/setup-go@v5 + with: + go-version: 1.22.5 + + - name: Set up python + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + uses: actions/setup-python@v5 + + - name: Tune the OS + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + run: | + # Limit local port range to not use ports that overlap with server side + # ports that we listen on. + sudo sysctl -w net.ipv4.ip_local_port_range="22768 65535" + # Increase the asynchronous non-blocking I/O. More information at https://dev.mysql.com/doc/refman/5.7/en/innodb-parameters.html#sysvar_innodb_use_native_aio + echo "fs.aio-max-nr = 1048576" | sudo tee -a /etc/sysctl.conf + sudo sysctl -p /etc/sysctl.conf + + - name: Get dependencies + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + run: | + # Get key to latest MySQL repo + sudo apt-key adv --keyserver keyserver.ubuntu.com --recv-keys A8D3785C + # Setup MySQL 8.0 + wget -c https://dev.mysql.com/get/mysql-apt-config_0.8.29-1_all.deb + echo mysql-apt-config mysql-apt-config/select-server select mysql-8.0 | sudo debconf-set-selections + sudo DEBIAN_FRONTEND="noninteractive" dpkg -i mysql-apt-config* + sudo apt-get -qq update + # Install everything else we need, and configure + sudo apt-get -qq install -y mysql-server mysql-client make unzip g++ etcd curl git wget eatmydata xz-utils libncurses5 + + sudo service mysql stop + sudo service etcd stop + sudo ln -s /etc/apparmor.d/usr.sbin.mysqld /etc/apparmor.d/disable/ + sudo apparmor_parser -R /etc/apparmor.d/usr.sbin.mysqld + go mod download + + # install JUnit report formatter + go install github.com/vitessio/go-junit-report@HEAD + + # install vitess tester + go install github.com/vitessio/vitess-tester@eb953122baba163ed8ccaa6642458ee984f5d7e4 + + - name: Setup launchable dependencies + if: steps.skip-workflow.outputs.is_draft == 'false' && steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' && github.base_ref == 'main' + run: | + # Get Launchable CLI installed. If you can, make it a part of the builder image to speed things up + pip3 install --user launchable~=1.0 > /dev/null + + # verify that launchable setup is all correct. + launchable verify || true + + # Tell Launchable about the build you are producing and testing + launchable record build --name "$GITHUB_RUN_ID" --no-commit-collection --source . + + - name: Run cluster endtoend test + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' + timeout-minutes: 45 + run: | + # We set the VTDATAROOT to the /tmp folder to reduce the file path of mysql.sock file + # which musn't be more than 107 characters long. + export VTDATAROOT="/tmp/" + source build.env + make build + + set -exo pipefail + + i=1 + for dir in {{.Path}}/*/; do + # We go over all the directories in the given path. + # If there is a vschema file there, we use it, otherwise we let vitess-tester autogenerate it. + if [ -f $dir/vschema.json ]; then + vitess-tester --sharded --xunit --test-dir $dir --vschema "$dir"vschema.json + else + vitess-tester --sharded --xunit --test-dir $dir + fi + # Number the reports by changing their file names. + mv report.xml report"$i".xml + i=$((i+1)) + done + + - name: Print test output and Record test result in launchable if PR is not a draft + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' && always() + run: | + if [[ "{{"${{steps.skip-workflow.outputs.is_draft}}"}}" == "false" ]]; then + # send recorded tests to launchable + launchable record tests --build "$GITHUB_RUN_ID" go-test . || true + fi + + # print test output + cat report*.xml + + - name: Test Summary + if: steps.skip-workflow.outputs.skip-workflow == 'false' && steps.changes.outputs.end_to_end == 'true' && always() + uses: test-summary/action@v2 + with: + paths: "report*.xml" + show: "fail, skip"