├── Data (Parquet files)
└── Parquet_files
├── Database
├── DuckDB
│ ├── Create_db_import.py
│ ├── Create_Empty_Tables.py
│ ├── duckdb.py
│ └── vertipaq.ipynb
├── snowflake
│ ├── TPCH_DuckDB_Generate_SF100.ipynb
│ └── full pipeline.sql
├── Fabric
│ └── Load TPCH.ipynb
├── BigQuery.sql
├── trino.sql
├── Synapse_serverless.sql
├── Snowflake+SingleStore+Databricks+alloyDB.sql
└── Sorting
│ └── testing_sort in Fabric.ipynb
├── LICENSE
├── results.csv
├── README.md
└── results_SF100.csv
/Data (Parquet files)/Parquet_files:
--------------------------------------------------------------------------------
1 | https://drive.google.com/drive/folders/1mZC3NuPBZC4mjP3_kH18c9fLrv8ME7RU
2 |
--------------------------------------------------------------------------------
/Database/DuckDB/Create_db_import.py:
--------------------------------------------------------------------------------
1 | import duckdb
2 | con = duckdb.connect(database='C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/db/tpch.duckdb')
3 |
4 |
5 | df=con.execute('''
6 | INSERT INTO partsupp select * FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/partsupp.parquet';
7 | INSERT INTO part select * FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/part.parquet' ;
8 | INSERT INTO supplier select * FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/supplier.parquet' ;
9 | INSERT INTO nation select * FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/nation.parquet';
10 | INSERT INTO region select * FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/region.parquet' ;
11 | INSERT INTO lineitem SELECT * FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/lineitem/lineitem.parquet';
12 | INSERT INTO orders select * FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/orders.parquet' ;
13 | INSERT INTO customer select * FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/customer.parquet'
14 | ''')
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | MIT License
2 |
3 | Copyright (c) 2025 Mimoune
4 |
5 | Permission is hereby granted, free of charge, to any person obtaining a copy
6 | of this software and associated documentation files (the "Software"), to deal
7 | in the Software without restriction, including without limitation the rights
8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 |
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE.
22 |
--------------------------------------------------------------------------------
/results.csv:
--------------------------------------------------------------------------------
1 | TPCH,Snowflake,PowerBI Datamart,SingleStore,BigQuery,Databricks,DuckDB
2 | '--Query01,1.5,1.69425,0.99,0.349,1.43,2.925584
3 | '--Query02,1.37,0.24475,0.56,1.866,1.47,0.587252
4 | '--Query03,0.88,0.48125,0.67,1.6245,2.79,1.929619
5 | '--Query04,0.78,0.317,1.33,1.1675,2.31,2.076801
6 | '--Query05,1.14,0.35625,0.69,2.822,4.73,1.741391
7 | '--Query06,0.36,0.028,0.38,0.223,0.848,1.367892
8 | '--Query07,1.09,0.23875,1.53,1.716,3.42,3.230886
9 | '--Query08,1.25,0.2905,0.49,1.83,2.67,2.335001
10 | '--Query09,1.81,2.11075,3.16,1.9955,3.79,18.031278
11 | '--Query10,1.23,3.57475,1.8,1.946,3.34,2.350712
12 | '--Query11,0.62,0.08725,0.19,1.087,0.866,0.361263
13 | '--Query12,0.92,0.127,0.4,1.042,1.95,2.919569
14 | '--Query13,2.18,12.7005,7.47,1.238,2.5,1.317222
15 | '--Query14,0.44,0.15,0.35,0.9795,1.34,1.684677
16 | '--Query15,0.79,0.13975,1.18,0.802,1.91,3.697779
17 | '--Query16,0.76,4.69775,1.41,4.463,1.6,0.846283
18 | '--Query17,0.7,0.12975,0.46,2.814,3.27,4.692349
19 | '--Query18,1.58,2.11775,2.72,2.289,5.46,5.46211
20 | '--Query19,0.68,0.06775,0.43,0.6835,1.44,3.187931
21 | '--Query20,0.83,0.799,4.55,1.0595,2.37,2.302849
22 | '--Query21,1.44,0.62375,1.58,1.767,7.6,7.64953
23 | '--Query22,0.77,0.179,0.83,1.25,1.32,0.653454
24 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # Update : added results for SF100
2 |
3 | Blog : https://datamonkeysite.com/2023/03/09/benchmarking-snowflake-databricks-synapse-bigquery-and-duckdb-using-tpch-sf100/
4 |
5 | # Testing OLAP SQL Engine using TPC-H
6 |
7 | it started as testing BigQuery BI engine for fun, but I did found it easy to test other Engine too, Please check this blog for Background
8 |
9 | https://datamonkeysite.com/2022/01/07/benchmark-snowflake-bigquery-singlestore-and-databricks-using-tpc-h-sf10/
10 |
11 | so Far Tested Snowflake, BigQuery, Databrciks SQL, SingleStore,DuckDB, and PowerBI Datamart, I only include DB that take less than 100 second to finish the benchmark
12 |
13 | it is not supposed to be very accurate or an official benchmark, but just to get a general impression of the performance.
14 |
15 | TPC-H reference : http://tpc.org/tpc_documents_current_versions/pdf/tpc-h_v3.0.0.pdf
16 |
17 |
18 |
19 | # BigQuery BI Engine
20 |
21 |
22 | The Original Purpose of the Benchmark was to troll BiQuery Product team to make all Queries accelerated by BI Engine :)
23 |
24 |
25 | Unfortunately not all Queries are accelerated by BigQuery BI Engine (Currently only 11)
26 |
27 | Currently BI Engine is limited to a join with 5 Million Dimension Table
28 |
29 | up to 5 Joins are supported
30 |
31 | see Current Limitations
32 | https://cloud.google.com/bi-engine/docs/sql-interface-overview#limitations
33 |
34 | TPC-H SF10 use up to 8 joins and a dimension Table with 15 Million Records.
35 |
36 | Results for BI Engine Only : https://datastudio.google.com/reporting/b162bcc1-baee-4af5-995f-6155c939d742/page/p_v72vuqfvqc
37 |
38 |
39 | # PowerBI Datamart
40 |
41 | it is the easiest to setup, loading data uses only GUI, I love it, but it is a read only DB, you can can't delete rows etc
42 |
43 | #Apache Spark
44 |
45 | added Pyspark, just for fun, all I can say, it is really slow in a single node system
46 |
--------------------------------------------------------------------------------
/results_SF100.csv:
--------------------------------------------------------------------------------
1 | TPCH,Snowflake (Native),BigQuery On Demand (Native),RedShift(Native),BigQuery Standard (Native),Databricks (Native),hyper (Native), ,BigQuery (Parquet),Trino (Parquet),Synapse (Parquet),DuckDB (Parquet)
2 | 1,6.994666666666667,2.077,15.43187667,16.3045,7.41,17.18262267112732,,10.777,10.686,23.350333333333335,22.936180114746
3 | 2,3.5086666666666666,4.971,27.97874467,5.4565,15.73,6.172731161117554,,7.675,5.952500000000001,41.72533333333334,8.427250623703
4 | 3,3.911,5.372,3.648000667,11.4955,25.83,14.267503261566162,,15.314,11.142,37.84233333333333,16.1324775218963
5 | 4,3.8176666666666663,3.104,1.81973,6.559,29.02,17.17249059677124,,8.992,8.5135,62.129999999999995,30.3116931915283
6 | 5,5.700666666666667,10.743,2.880673667,25.185,57.18,19.923407316207886,,12.527,14.4185,17.306666666666644,28.5420212745666
7 | 6,0.38866666666666666,0.785,0.396908,1.3625,0.893,0.6273391246795654,,3.892,2.58,10.963333333333367,2.63828635215759
8 | 7,4.152,3.363,3.529426,6.3065,24.62,9.083648443222046,,18.143,23.848,11.294666666666643,44.4404926300048
9 | 8,3.951,12.047,2.374216667,26.5775,15.77,11.11404275894165,,15.673,30.007,18.162000000000006,30.5181167125701
10 | 9,8.044,6.887,6.988858333,44.3975,44.16,36.08943319320679,,16.099,37.172,30.11433333333335,78.5959200859069
11 | 10,9.119,4.289,3.613828333,13.2095,25.17,21.77272367477417,,13.284,9.536,47.50433333333331,19.5732061862945
12 | 11,1.2433333333333334,2.913,0.700923,5.3575,12.7,2.324084520339966,,12.509,7.019,16.173333333333346,4.38109540939331
13 | 12,1.6606666666666667,1.487,1.622724,2.7995,12.75,10.45216965675354,,4.142,5.35,15.59033333333332,8.33109068870544
14 | 13,8.9715,4.577,6.523660333,19.45,25.82,65.51695537567139,,10.337,8.977,19.571000000000026,25.2469310760498
15 | 14,0.9055,1.211,1.116808333,1.8135,3.21,7.630138397216797,,6.35,1.821,13.294333333333327,2.63200592994689
16 | 15,1.797,2.772,1.453118333,2.111,5.09,5.5513529777526855,,7.465,4.318,5.588999999999999,4.55331897735595
17 | 16,4.7715,6.896,1.808659333,12.3135,7.27,5.110839605331421,,13.012,4.136,30.137333333333345,4.92480158805847
18 | 17,2.6225,9.507,1.444940667,30.1505,99.6,24.08917260169983,,21.446,25.256,22.750666666666632,72.5051896572113
19 | 18,16.963,17.205,47.09592733,39.1625,94.2,,,48.357,40.419,56.73866666666669,131.368780136108
20 | 19,2.792,1.451,5.421843333,13.7385,6.66,7.249908685684204,,11.567,7.665,22.292333333333318,24.6245656013488
21 | 20,1.4645,4.796,2.750811667,6.433999999999999,20.2,5.3154003620147705,,9.062,7.638,28.019666666666637,20.7155916690826
22 | 21,10.7535,17.69,10.15324967,26.861,124.2,46.56257677078247,,26.005,57.928,33.569000000000074,
23 | 22,1.545,1.607,2.103871,2.3739999999999997,9.11,6.4549665451049805,,7.803,3.13,38.900999999999954,
24 |
--------------------------------------------------------------------------------
/Database/snowflake/TPCH_DuckDB_Generate_SF100.ipynb:
--------------------------------------------------------------------------------
1 | {
2 | "cells": [
3 | {
4 | "cell_type": "markdown",
5 | "metadata": {
6 | "id": "wq5HHFy_fbze"
7 | },
8 | "source": [
9 | "# Generate TPCH Parquet files"
10 | ]
11 | },
12 | {
13 | "cell_type": "code",
14 | "execution_count": 1,
15 | "metadata": {
16 | "id": "MDTt42NXEL5_"
17 | },
18 | "outputs": [],
19 | "source": [
20 | "sf=100"
21 | ]
22 | },
23 | {
24 | "cell_type": "code",
25 | "execution_count": null,
26 | "metadata": {
27 | "colab": {
28 | "base_uri": "https://localhost:8080/"
29 | },
30 | "id": "mgc_2GlVfJSt",
31 | "outputId": "2a53928e-60e7-42f3-c53a-92c45b4abc04"
32 | },
33 | "outputs": [],
34 | "source": [
35 | "!pip install duckdb --pre --upgrade > /dev/null 2>&1\n",
36 | "!pip show duckdb"
37 | ]
38 | },
39 | {
40 | "cell_type": "code",
41 | "execution_count": 3,
42 | "metadata": {
43 | "colab": {
44 | "base_uri": "https://localhost:8080/"
45 | },
46 | "id": "kFQ0KCKYfMCx",
47 | "outputId": "9d2d51df-e705-4424-a608-6fe27e98378b"
48 | },
49 | "outputs": [
50 | {
51 | "name": "stdout",
52 | "output_type": "stream",
53 | "text": [
54 | "CPU times: user 48min 27s, sys: 1min 50s, total: 50min 18s\n",
55 | "Wall time: 24min 32s\n"
56 | ]
57 | }
58 | ],
59 | "source": [
60 | "%%time\n",
61 | "import duckdb\n",
62 | "import pathlib\n",
63 | "\n",
64 | "\n",
65 | "for x in range(0, sf) :\n",
66 | " con=duckdb.connect()\n",
67 | " con.sql('PRAGMA disable_progress_bar;SET preserve_insertion_order=false')\n",
68 | " con.sql(f\"CALL dbgen(sf={sf} , children ={sf}, step = {x})\") \n",
69 | " for tbl in ['nation','region','customer','supplier','lineitem','orders','partsupp','part'] :\n",
70 | " pathlib.Path(f'{sf}/{tbl}').mkdir(parents=True, exist_ok=True) \n",
71 | " con.sql(f\"COPY (SELECT * FROM {tbl}) TO '{sf}/{tbl}/{x:02d}.parquet' \")\n",
72 | " con.close()"
73 | ]
74 | }
75 | ],
76 | "metadata": {
77 | "colab": {
78 | "provenance": []
79 | },
80 | "environment": {
81 | "kernel": "python3",
82 | "name": "common-cpu.m106",
83 | "type": "gcloud",
84 | "uri": "gcr.io/deeplearning-platform-release/base-cpu:m106"
85 | },
86 | "kernelspec": {
87 | "display_name": "Python 3",
88 | "language": "python",
89 | "name": "python3"
90 | },
91 | "language_info": {
92 | "codemirror_mode": {
93 | "name": "ipython",
94 | "version": 3
95 | },
96 | "file_extension": ".py",
97 | "mimetype": "text/x-python",
98 | "name": "python",
99 | "nbconvert_exporter": "python",
100 | "pygments_lexer": "ipython3",
101 | "version": "3.7.12"
102 | },
103 | "vscode": {
104 | "interpreter": {
105 | "hash": "a00db2a08d8e812a7e35133a98e8cfd4141d13fcbd55f5b6e55385387fe8d2b4"
106 | }
107 | }
108 | },
109 | "nbformat": 4,
110 | "nbformat_minor": 4
111 | }
112 |
--------------------------------------------------------------------------------
/Database/DuckDB/Create_Empty_Tables.py:
--------------------------------------------------------------------------------
1 | import duckdb
2 | con = duckdb.connect(database='C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/db/tpch.duckdb')
3 | con.execute("PRAGMA default_collation='nocase';")
4 |
5 |
6 | df =con.execute('''
7 |
8 |
9 | DROP TABLE IF EXISTS PART ;
10 | CREATE TABLE PART (
11 |
12 | P_PARTKEY INTEGER PRIMARY KEY,
13 | P_NAME VARCHAR(55),
14 | P_MFGR CHAR(25),
15 | P_BRAND CHAR(10),
16 | P_TYPE VARCHAR(25),
17 | P_SIZE INTEGER,
18 | P_CONTAINER CHAR(10),
19 | P_RETAILPRICE DECIMAL,
20 | P_COMMENT VARCHAR(23)
21 | );
22 |
23 | DROP TABLE IF EXISTS SUPPLIER;
24 | CREATE TABLE SUPPLIER (
25 | S_SUPPKEY INTEGER PRIMARY KEY,
26 | S_NAME CHAR(25),
27 | S_ADDRESS VARCHAR(40),
28 | S_NATIONKEY INTEGER NOT NULL, -- references N_NATIONKEY
29 | S_PHONE CHAR(15),
30 | S_ACCTBAL DECIMAL,
31 | S_COMMENT VARCHAR(101)
32 | );
33 |
34 | DROP TABLE IF EXISTS PARTSUPP;
35 | CREATE TABLE PARTSUPP (
36 | PS_PARTKEY INTEGER NOT NULL, -- references P_PARTKEY
37 | PS_SUPPKEY INTEGER NOT NULL, -- references S_SUPPKEY
38 | PS_AVAILQTY INTEGER,
39 | PS_SUPPLYCOST DECIMAL,
40 | PS_COMMENT VARCHAR(199),
41 | PRIMARY KEY (PS_PARTKEY, PS_SUPPKEY)
42 | );
43 |
44 | DROP TABLE IF EXISTS CUSTOMER;
45 | CREATE TABLE CUSTOMER (
46 | C_CUSTKEY INTEGER PRIMARY KEY,
47 | C_NAME VARCHAR(25),
48 | C_ADDRESS VARCHAR(40),
49 | C_NATIONKEY INTEGER NOT NULL, -- references N_NATIONKEY
50 | C_PHONE CHAR(15),
51 | C_ACCTBAL DECIMAL,
52 | C_MKTSEGMENT CHAR(10),
53 | C_COMMENT VARCHAR(117)
54 | );
55 |
56 | DROP TABLE IF EXISTS ORDERS;
57 | CREATE TABLE ORDERS (
58 | O_ORDERKEY INTEGER PRIMARY KEY,
59 | O_CUSTKEY INTEGER NOT NULL, -- references C_CUSTKEY
60 | O_ORDERSTATUS CHAR(1),
61 | O_TOTALPRICE DECIMAL,
62 | O_ORDERPRIORITY CHAR(15),
63 | O_CLERK CHAR(15),
64 | O_SHIPPRIORITY INTEGER,
65 | O_COMMENT VARCHAR(79),
66 | O_ORDERDATE DATE,
67 | );
68 |
69 | DROP TABLE IF EXISTS LINEITEM;
70 | CREATE TABLE LINEITEM (
71 | L_ORDERKEY INTEGER NOT NULL, -- references O_ORDERKEY
72 | L_PARTKEY INTEGER NOT NULL, -- references P_PARTKEY (compound fk to PARTSUPP)
73 | L_SUPPKEY INTEGER NOT NULL, -- references S_SUPPKEY (compound fk to PARTSUPP)
74 | L_LINENUMBER INTEGER,
75 | L_QUANTITY DECIMAL,
76 | L_EXTENDEDPRICE DECIMAL,
77 | L_DISCOUNT DECIMAL,
78 | L_TAX DECIMAL,
79 | L_RETURNFLAG CHAR(1),
80 | L_LINESTATUS CHAR(1),
81 | L_SHIPINSTRUCT CHAR(25),
82 | L_SHIPMODE CHAR(10),
83 | L_COMMENT VARCHAR(44),
84 | L_SHIPDATE DATE,
85 | L_COMMITDATE DATE,
86 | L_RECEIPTDATE DATE,
87 | PRIMARY KEY (L_ORDERKEY, L_LINENUMBER)
88 | );
89 |
90 | DROP TABLE IF EXISTS NATION;
91 | CREATE TABLE NATION (
92 | N_NATIONKEY INTEGER PRIMARY KEY,
93 | N_NAME CHAR(25),
94 | N_REGIONKEY INTEGER NOT NULL, -- references R_REGIONKEY
95 | N_COMMENT VARCHAR(152)
96 | );
97 |
98 | DROP TABLE IF EXISTS REGION;
99 | CREATE TABLE REGION (
100 | R_REGIONKEY INTEGER PRIMARY KEY,
101 | R_NAME CHAR(25),
102 | R_COMMENT VARCHAR(152)
103 | );
104 |
105 | ''')
--------------------------------------------------------------------------------
/Database/Fabric/Load TPCH.ipynb:
--------------------------------------------------------------------------------
1 | {"nbformat":4,"nbformat_minor":0,"metadata":{"language_info":{"name":"python"},"kernelspec":{"name":"synapse_pyspark","display_name":"Synapse PySpark"},"widgets":{},"kernel_info":{"name":"synapse_pyspark"},"save_output":true,"spark_compute":{"compute_id":"/trident/default","session_options":{"enableDebugMode":false,"conf":{}}},"notebook_environment":{},"synapse_widget":{"version":"0.1","state":{}},"trident":{"lakehouse":{"known_lakehouses":[{"id":"1d9313ec-93d9-4e1a-8a2c-4076c2573e09"}],"default_lakehouse_workspace_id":"9412703d-2efe-46e7-8b12-64772dd4b90f","default_lakehouse":"1d9313ec-93d9-4e1a-8a2c-4076c2573e09","default_lakehouse_name":"TPCH"}}},"cells":[{"cell_type":"code","source":["!pip install duckdb --pre --upgrade"],"outputs":[],"execution_count":null,"metadata":{"jupyter":{"source_hidden":false,"outputs_hidden":false},"nteract":{"transient":{"deleting":false}}}},{"cell_type":"code","source":["sf =100"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"bd700cbb-3a21-4159-a7e0-8e12ae495dad","statement_id":4,"state":"finished","livy_statement_state":"available","queued_time":"2023-05-29T22:38:41.0045266Z","session_start_time":null,"execution_start_time":"2023-05-29T22:38:55.6727527Z","execution_finish_time":"2023-05-29T22:38:56.0484833Z","spark_jobs":{"numbers":{"FAILED":0,"RUNNING":0,"SUCCEEDED":0,"UNKNOWN":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"deb919ea-3f10-4b66-8c1c-c190d957a123"},"text/plain":"StatementMeta(, bd700cbb-3a21-4159-a7e0-8e12ae495dad, 4, Finished, Available)"},"metadata":{}}],"execution_count":2,"metadata":{"jupyter":{"source_hidden":false,"outputs_hidden":false},"nteract":{"transient":{"deleting":false}}}},{"cell_type":"code","source":["%%time\r\n","import duckdb\r\n","import pathlib\r\n","for x in range(0, sf) :\r\n"," con=duckdb.connect()\r\n"," con.sql('PRAGMA disable_progress_bar;SET preserve_insertion_order=false')\r\n"," con.sql(f\"CALL dbgen(sf={sf} , children ={sf}, step = {x})\") \r\n"," for tbl in ['nation','region','customer','supplier','lineitem','orders','partsupp','part'] :\r\n"," pathlib.Path(f'/lakehouse/default/Files/{sf}/{tbl}').mkdir(parents=True, exist_ok=True) \r\n"," con.sql(f\"COPY (SELECT * FROM {tbl}) TO '/lakehouse/default/Files/{sf}/{tbl}/{x:02d}.parquet' \")\r\n"," con.close()"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"bd700cbb-3a21-4159-a7e0-8e12ae495dad","statement_id":5,"state":"submitted","livy_statement_state":"running","queued_time":"2023-05-29T22:38:41.0067236Z","session_start_time":null,"execution_start_time":"2023-05-29T22:38:56.6294766Z","execution_finish_time":null,"spark_jobs":{"numbers":{"FAILED":0,"RUNNING":0,"SUCCEEDED":0,"UNKNOWN":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"ce48fd67-7915-4bbe-aaac-8eb80bd828a1"},"text/plain":"StatementMeta(, bd700cbb-3a21-4159-a7e0-8e12ae495dad, 5, Submitted, Running)"},"metadata":{}},{"output_type":"stream","name":"stdout","text":["CPU times: user 56min 36s, sys: 2min 31s, total: 59min 8s\nWall time: 25min 50s\n"]}],"execution_count":3,"metadata":{"jupyter":{"source_hidden":false,"outputs_hidden":false},"nteract":{"transient":{"deleting":false}}}},{"cell_type":"code","source":["spark.conf.set(\"spark.sql.parquet.vorder.enabled\", \"true\")\r\n","spark.conf.set(\"spark.microsoft.delta.optimizeWrite.enabled\", \"true\")"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":null,"statement_id":null,"state":"waiting","livy_statement_state":null,"queued_time":"2023-05-29T22:38:41.0073124Z","session_start_time":null,"execution_start_time":null,"execution_finish_time":null,"spark_jobs":null,"parent_msg_id":"746c76c4-3245-4907-8d26-39f1b40493a2"},"text/plain":"StatementMeta(, , , Waiting, )"},"metadata":{}}],"execution_count":4,"metadata":{"jupyter":{"source_hidden":false,"outputs_hidden":false},"nteract":{"transient":{"deleting":false}}}},{"cell_type":"code","source":["from pyspark.sql.types import *\n","def loadFullDataFromSource(table_name):\n"," df = spark.read.parquet(f'Files/{sf}/' + table_name + '/*.parquet')\n"," df.write.mode(\"overwrite\").format(\"delta\").save(f\"Tables/\" + table_name)\n","full_tables = [\n"," 'customer',\n"," 'lineitem',\n"," 'nation',\n"," 'orders' ,\n"," 'region',\n"," 'partsupp',\n"," 'supplier' ,\n"," 'part'\n"," ]\n","\n","for table in full_tables:\n"," loadFullDataFromSource(table)"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":null,"statement_id":null,"state":"waiting","livy_statement_state":null,"queued_time":"2023-05-29T22:38:41.0084097Z","session_start_time":null,"execution_start_time":null,"execution_finish_time":null,"spark_jobs":null,"parent_msg_id":"901bb8c7-6dd0-456e-97d6-7c4d52652e01"},"text/plain":"StatementMeta(, , , Waiting, )"},"metadata":{}}],"execution_count":5,"metadata":{}}]}
--------------------------------------------------------------------------------
/Database/snowflake/full pipeline.sql:
--------------------------------------------------------------------------------
1 | create DATABASE IDENTIFIER('"TPCH"') COMMENT = '' ;
2 | USE TPCH ;
3 | create or replace schema EXTERNAL ;
4 | USE TPCH.EXTERNAL ;
5 |
6 | CREATE OR REPLACE STAGE my_azure_stage
7 | URL='azure://yyyy.blob.core.windows.net/xxxx'
8 | CREDENTIALS=(AZURE_SAS_TOKEN='xxxxxxxxxxxxxxxxx') ;
9 |
10 |
11 | CREATE OR REPLACE FILE FORMAT my_parquet_format
12 | TYPE = PARQUET
13 | COMPRESSION = SNAPPY;
14 |
15 | -- notice that snowflake is case sensitive, I changed field name to capital
16 |
17 | create or replace external table TPCH.EXTERNAL_TABLE.CUSTOMER(
18 | "C_ACCTBAL" NUMBER(15,2) AS (CAST(GET($1, 'c_acctbal') AS NUMBER(15,2))),
19 | "C_MKTSEGMENT" VARCHAR(10) AS (CAST(GET($1, 'c_mktsegment') AS VARCHAR(10))),
20 | "C_ADDRESS" VARCHAR(40) AS (CAST(GET($1, 'c_address') AS VARCHAR(40))),
21 | "C_COMMENT" VARCHAR(117) AS (CAST(GET($1, 'c_comment') AS VARCHAR(117))),
22 | "C_NATIONKEY" NUMBER(38,0) AS (CAST(GET($1, 'c_nationkey') AS NUMBER(38,0))),
23 | "C_NAME" VARCHAR(25) AS (CAST(GET($1, 'c_name') AS VARCHAR(25))),
24 | "C_CUSTKEY" NUMBER(38,0) AS (CAST(GET($1, 'c_custkey') AS NUMBER(38,0))),
25 | "C_PHONE" VARCHAR(16777216) AS (CAST(GET($1, 'c_phone') AS VARCHAR(15))))
26 | location=@MY_AZURE_STAGE/customer/
27 | auto_refresh=false
28 | file_format=my_parquet_format
29 | ;
30 |
31 | create or replace external table TPCH.EXTERNAL_TABLE.LINEITEM(
32 | "L_SHIPDATE" DATE AS (CAST(GET($1, 'l_shipdate') AS DATE)),
33 | "L_COMMITDATE" DATE AS (CAST(GET($1, 'l_commitdate') AS DATE)),
34 | "L_QUANTITY" NUMBER(38,0) AS (CAST(GET($1, 'l_quantity') AS NUMBER(38,0))),
35 | "L_EXTENDEDPRICE" NUMBER(15,2) AS (CAST(GET($1, 'l_extendedprice') AS NUMBER(15,2))),
36 | "L_SUPPKEY" NUMBER(38,0) AS (CAST(GET($1, 'l_suppkey') AS NUMBER(38,0))),
37 | "L_LINENUMBER" NUMBER(38,0) AS (CAST(GET($1, 'l_linenumber') AS NUMBER(38,0))),
38 | "L_DISCOUNT" NUMBER(15,2) AS (CAST(GET($1, 'l_discount') AS NUMBER(15,2))),
39 | "L_TAX" NUMBER(15,2) AS (CAST(GET($1, 'l_tax') AS NUMBER(15,2))),
40 | "L_ORDERKEY" NUMBER(38,0) AS (CAST(GET($1, 'l_orderkey') AS NUMBER(38,0))),
41 | "L_PARTKEY" NUMBER(38,0) AS (CAST(GET($1, 'l_partkey') AS NUMBER(38,0))),
42 | "L_RECEIPTDATE" DATE AS (CAST(GET($1, 'l_receiptdate') AS DATE)),
43 | "L_SHIPINSTRUCT" VARCHAR(25) AS (CAST(GET($1, 'l_shipinstruct') AS VARCHAR(25))),
44 | "L_SHIPMODE" VARCHAR(10) AS (CAST(GET($1, 'l_shipmode') AS VARCHAR(10))),
45 | "L_COMMENT" VARCHAR(44) AS (CAST(GET($1, 'l_comment') AS VARCHAR(44))),
46 | "L_RETURNFLAG" VARCHAR(1) AS (CAST(GET($1, 'l_returnflag') AS VARCHAR(1))),
47 | "L_LINESTATUS" VARCHAR(1) AS (CAST(GET($1, 'l_linestatus') AS VARCHAR(1))))
48 | location=@MY_AZURE_STAGE/lineitem/
49 | auto_refresh=false
50 | file_format=my_parquet_format
51 | ;
52 |
53 | create or replace external table TPCH.EXTERNAL_TABLE.NATION(
54 | "N_NATIONKEY" NUMBER(38,0) AS (CAST(GET($1, 'n_nationkey') AS NUMBER(38,0))),
55 | "N_REGIONKEY" NUMBER(38,0) AS (CAST(GET($1, 'n_regionkey') AS NUMBER(38,0))),
56 | "N_COMMENT" VARCHAR(152) AS (CAST(GET($1, 'n_comment') AS VARCHAR(152))),
57 | "N_NAME" VARCHAR(25) AS (CAST(GET($1, 'n_name') AS VARCHAR(25))))
58 | location=@MY_AZURE_STAGE/nation/
59 | auto_refresh=false
60 | file_format=my_parquet_format
61 | ;
62 |
63 | create or replace external table TPCH.EXTERNAL_TABLE.ORDERS(
64 | "O_SHIPPRIORITY" NUMBER(38,0) AS (CAST(GET($1, 'o_shippriority') AS NUMBER(38,0))),
65 | "O_COMMENT" VARCHAR(79) AS (CAST(GET($1, 'o_comment') AS VARCHAR(79))),
66 | "O_ORDERPRIORITY" VARCHAR(15) AS (CAST(GET($1, 'o_orderpriority') AS VARCHAR(15))),
67 | "O_CLERK" VARCHAR(15) AS (CAST(GET($1, 'o_clerk') AS VARCHAR(15))),
68 | "O_ORDERDATE" DATE AS (CAST(GET($1, 'o_orderdate') AS DATE)),
69 | "O_ORDERSTATUS" VARCHAR(1) AS (CAST(GET($1, 'o_orderstatus') AS VARCHAR(1))),
70 | "O_TOTALPRICE" NUMBER(15,2) AS (CAST(GET($1, 'o_totalprice') AS NUMBER(15,2))),
71 | "O_ORDERKEY" NUMBER(38,0) AS (CAST(GET($1, 'o_orderkey') AS NUMBER(38,0))),
72 | "O_CUSTKEY" NUMBER(38,0) AS (CAST(GET($1, 'o_custkey') AS NUMBER(38,0))))
73 | location=@MY_AZURE_STAGE/orders/
74 | auto_refresh=false
75 | file_format=my_parquet_format
76 | ;
77 |
78 | create or replace external table TPCH.EXTERNAL_TABLE.PART(
79 | "P_NAME" VARCHAR(55) AS (CAST(GET($1, 'p_name') AS VARCHAR(55))),
80 | "P_PARTKEY" NUMBER(38,0) AS (CAST(GET($1, 'p_partkey') AS NUMBER(38,0))),
81 | "P_SIZE" NUMBER(38,0) AS (CAST(GET($1, 'p_size') AS NUMBER(38,0))),
82 | "P_COMMENT" VARCHAR(23) AS (CAST(GET($1, 'p_comment') AS VARCHAR(23))),
83 | "P_TYPE" VARCHAR(25) AS (CAST(GET($1, 'p_type') AS VARCHAR(25))),
84 | "P_CONTAINER" VARCHAR(10) AS (CAST(GET($1, 'p_container') AS VARCHAR(10))),
85 | "P_RETAILPRICE" NUMBER(15,2) AS (CAST(GET($1, 'p_retailprice') AS NUMBER(15,2))),
86 | "P_MFGR" VARCHAR(25) AS (CAST(GET($1, 'p_mfgr') AS VARCHAR(25))),
87 | "P_BRAND" VARCHAR(10) AS (CAST(GET($1, 'p_brand') AS VARCHAR(10))))
88 | location=@MY_AZURE_STAGE/part/
89 | auto_refresh=false
90 | file_format=my_parquet_format
91 | ;
92 |
93 | create or replace external table TPCH.EXTERNAL_TABLE.PARTSUPP(
94 | "PS_SUPPKEY" NUMBER(38,0) AS (CAST(GET($1, 'ps_suppkey') AS NUMBER(38,0))),
95 | "PS_PARTKEY" NUMBER(38,0) AS (CAST(GET($1, 'ps_partkey') AS NUMBER(38,0))),
96 | "PS_AVAILQTY" NUMBER(38,0) AS (CAST(GET($1, 'ps_availqty') AS NUMBER(38,0))),
97 | "PS_SUPPLYCOST" NUMBER(15,2) AS (CAST(GET($1, 'ps_supplycost') AS NUMBER(15,2))),
98 | "PS_COMMENT" VARCHAR(199) AS (CAST(GET($1, 'ps_comment') AS VARCHAR(199))))
99 | location=@MY_AZURE_STAGE/partsupp/
100 | auto_refresh=false
101 | file_format=my_parquet_format
102 | ;
103 |
104 | create or replace external table TPCH.EXTERNAL_TABLE.REGION(
105 | "R_COMMENT" VARCHAR(152) AS (CAST(GET($1, 'r_comment') AS VARCHAR(152))),
106 | "R_REGIONKEY" NUMBER(38,0) AS (CAST(GET($1, 'r_regionkey') AS NUMBER(38,0))),
107 | "R_NAME" VARCHAR(25) AS (CAST(GET($1, 'r_name') AS VARCHAR(25))))
108 | location=@MY_AZURE_STAGE/region/
109 | auto_refresh=false
110 | file_format=my_parquet_format
111 | ;
112 |
113 | create or replace external table TPCH.EXTERNAL_TABLE.SUPPLIER(
114 | "S_NAME" VARCHAR(25) AS (CAST(GET($1, 's_name') AS VARCHAR(25))),
115 | "S_ADDRESS" VARCHAR(40) AS (CAST(GET($1, 's_address') AS VARCHAR(40))),
116 | "S_SUPPKEY" NUMBER(38,0) AS (CAST(GET($1, 's_suppkey') AS NUMBER(38,0))),
117 | "S_ACCTBAL" NUMBER(15,2) AS (CAST(GET($1, 's_acctbal') AS NUMBER(15,2))),
118 | "S_PHONE" VARCHAR(15) AS (CAST(GET($1, 's_phone') AS VARCHAR(15))),
119 | "S_COMMENT" VARCHAR(101) AS (CAST(GET($1, 's_comment') AS VARCHAR(101))),
120 | "S_NATIONKEY" NUMBER(38,0) AS (CAST(GET($1, 's_nationkey') AS NUMBER(38,0))))
121 | location=@MY_AZURE_STAGE/supplier/
122 | auto_refresh=false
123 | file_format=my_parquet_format
124 | ;
125 |
126 | --Load data to Snowflake DB
127 | USE TPCH
128 | create or replace schema internal ;
129 | create or replace table lineitem as select L_SHIPDATE, L_COMMITDATE, L_QUANTITY, L_EXTENDEDPRICE,
130 | L_SUPPKEY, L_LINENUMBER, L_DISCOUNT, L_TAX, L_ORDERKEY, L_PARTKEY, L_RECEIPTDATE, L_SHIPINSTRUCT,
131 | L_SHIPMODE, L_COMMENT, L_RETURNFLAG, L_LINESTATUS from tpch.external_table.lineitem ;
132 |
133 | create or replace table orders as select O_SHIPPRIORITY, O_COMMENT, O_ORDERPRIORITY,
134 | O_CLERK, O_ORDERDATE, O_ORDERSTATUS, O_TOTALPRICE, O_ORDERKEY, O_CUSTKEY from tpch.external_table.orders ;
135 |
136 | create or replace table customer as select C_ACCTBAL, C_MKTSEGMENT, C_ADDRESS, C_COMMENT,
137 | C_NATIONKEY, C_NAME, C_CUSTKEY, C_PHONE from tpch.external_table.customer ;
138 |
139 | create or replace table nation as select N_NATIONKEY, N_REGIONKEY, N_COMMENT, N_NAME from tpch.external_table.nation ;
140 |
141 | create or replace table region as select R_REGIONKEY, R_NAME , R_COMMENT from tpch.external_table.region ;
142 |
143 | create or replace table part as select P_NAME, P_PARTKEY, P_SIZE, P_COMMENT, P_TYPE, P_CONTAINER,
144 | P_RETAILPRICE, P_MFGR, P_BRAND from tpch.external_table.part ;
145 |
146 | create or replace table partsupp as select PS_SUPPKEY, PS_PARTKEY, PS_AVAILQTY, PS_SUPPLYCOST, PS_COMMENT from tpch.external_table.partsupp ;
147 |
148 | create or replace table supplier as select S_NAME, S_ADDRESS, S_SUPPKEY, S_ACCTBAL, S_PHONE, S_COMMENT, S_NATIONKEY from tpch.external_table.supplier ;
149 |
--------------------------------------------------------------------------------
/Database/BigQuery.sql:
--------------------------------------------------------------------------------
1 | -- TPC-H SF10
2 | set @@dataset_project_id="test-187010";
3 | set @@dataset_id="TPCH";
4 | SELECT
5 | --Query01
6 | l_returnflag,
7 | l_linestatus,
8 | SUM(l_quantity) AS sum_qty,
9 | SUM(l_extendedprice) AS sum_base_price,
10 | SUM(l_extendedprice * (1 - l_discount)) AS sum_disc_price,
11 | SUM(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge,
12 | AVG(l_quantity) AS avg_qty,
13 | AVG(l_extendedprice) AS avg_price,
14 | AVG(l_discount) AS avg_disc,
15 | COUNT(*) AS count_order
16 | FROM
17 | lineitem
18 | WHERE
19 | l_shipdate <= CAST('1998-09-02' AS date)
20 | GROUP BY
21 | l_returnflag,
22 | l_linestatus
23 | ORDER BY
24 | l_returnflag,
25 | l_linestatus;
26 | SELECT
27 | --Query02
28 | s_acctbal,
29 | s_name,
30 | n_name,
31 | p_partkey,
32 | p_mfgr,
33 | s_address,
34 | s_phone,
35 | s_comment
36 | FROM
37 | part,
38 | supplier,
39 | partsupp,
40 | nation,
41 | region
42 | WHERE
43 | p_partkey = ps_partkey
44 | AND s_suppkey = ps_suppkey
45 | AND p_size = 15
46 | AND p_type LIKE '%BRASS'
47 | AND s_nationkey = n_nationkey
48 | AND n_regionkey = r_regionkey
49 | AND r_name = 'EUROPE'
50 | AND ps_supplycost = (
51 | SELECT
52 | MIN(ps_supplycost)
53 | FROM
54 | partsupp,
55 | supplier,
56 | nation,
57 | region
58 | WHERE
59 | p_partkey = ps_partkey
60 | AND s_suppkey = ps_suppkey
61 | AND s_nationkey = n_nationkey
62 | AND n_regionkey = r_regionkey
63 | AND r_name = 'EUROPE')
64 | ORDER BY
65 | s_acctbal DESC,
66 | n_name,
67 | s_name,
68 | p_partkey
69 | LIMIT
70 | 100;
71 | SELECT
72 | --Query03
73 | l_orderkey,
74 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
75 | o_orderdate,
76 | o_shippriority
77 | FROM
78 | customer,
79 | orders,
80 | lineitem
81 | WHERE
82 | c_mktsegment = 'BUILDING'
83 | AND c_custkey = o_custkey
84 | AND l_orderkey = o_orderkey
85 | AND o_orderdate < CAST('1995-03-15' AS date)
86 | AND l_shipdate > CAST('1995-03-15' AS date)
87 | GROUP BY
88 | l_orderkey,
89 | o_orderdate,
90 | o_shippriority
91 | ORDER BY
92 | revenue DESC,
93 | o_orderdate
94 | LIMIT
95 | 10;
96 | SELECT
97 | --Query04
98 | o_orderpriority,
99 | COUNT(*) AS order_count
100 | FROM
101 | orders
102 | WHERE
103 | o_orderdate >= CAST('1993-07-01' AS date)
104 | AND o_orderdate < CAST('1993-10-01' AS date)
105 | AND EXISTS (
106 | SELECT
107 | *
108 | FROM
109 | lineitem
110 | WHERE
111 | l_orderkey = o_orderkey
112 | AND l_commitdate < l_receiptdate)
113 | GROUP BY
114 | o_orderpriority
115 | ORDER BY
116 | o_orderpriority;
117 | SELECT
118 | --Query05
119 | n_name,
120 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
121 | FROM
122 | customer,
123 | orders,
124 | lineitem,
125 | supplier,
126 | nation,
127 | region
128 | WHERE
129 | c_custkey = o_custkey
130 | AND l_orderkey = o_orderkey
131 | AND l_suppkey = s_suppkey
132 | AND c_nationkey = s_nationkey
133 | AND s_nationkey = n_nationkey
134 | AND n_regionkey = r_regionkey
135 | AND r_name = 'ASIA'
136 | AND o_orderdate >= CAST('1994-01-01' AS date)
137 | AND o_orderdate < CAST('1995-01-01' AS date)
138 | GROUP BY
139 | n_name
140 | ORDER BY
141 | revenue DESC;
142 | SELECT
143 | --Query06
144 | SUM(l_extendedprice * l_discount) AS revenue
145 | FROM
146 | lineitem
147 | WHERE
148 | l_shipdate >= CAST('1994-01-01' AS date)
149 | AND l_shipdate < CAST('1995-01-01' AS date)
150 | AND l_discount BETWEEN 0.05
151 | AND 0.07
152 | AND l_quantity < 24;
153 | SELECT
154 | --Query07
155 | supp_nation,
156 | cust_nation,
157 | l_year,
158 | SUM(volume) AS revenue
159 | FROM (
160 | SELECT
161 | n1.n_name AS supp_nation,
162 | n2.n_name AS cust_nation,
163 | EXTRACT(year
164 | FROM
165 | l_shipdate) AS l_year,
166 | l_extendedprice * (1 - l_discount) AS volume
167 | FROM
168 | supplier,
169 | lineitem,
170 | orders,
171 | customer,
172 | nation n1,
173 | nation n2
174 | WHERE
175 | s_suppkey = l_suppkey
176 | AND o_orderkey = l_orderkey
177 | AND c_custkey = o_custkey
178 | AND s_nationkey = n1.n_nationkey
179 | AND c_nationkey = n2.n_nationkey
180 | AND ((n1.n_name = 'FRANCE'
181 | AND n2.n_name = 'GERMANY')
182 | OR (n1.n_name = 'GERMANY'
183 | AND n2.n_name = 'FRANCE'))
184 | AND l_shipdate BETWEEN CAST('1995-01-01' AS date)
185 | AND CAST('1996-12-31' AS date)) AS shipping
186 | GROUP BY
187 | supp_nation,
188 | cust_nation,
189 | l_year
190 | ORDER BY
191 | supp_nation,
192 | cust_nation,
193 | l_year;
194 | SELECT
195 | --Query08
196 | o_year,
197 | SUM(
198 | CASE
199 | WHEN nation = 'BRAZIL' THEN volume
200 | ELSE
201 | 0
202 | END
203 | ) / SUM(volume) AS mkt_share
204 | FROM (
205 | SELECT
206 | EXTRACT(year
207 | FROM
208 | o_orderdate) AS o_year,
209 | l_extendedprice * (1 - l_discount) AS volume,
210 | n2.n_name AS nation
211 | FROM
212 | part,
213 | supplier,
214 | lineitem,
215 | orders,
216 | customer,
217 | nation n1,
218 | nation n2,
219 | region
220 | WHERE
221 | p_partkey = l_partkey
222 | AND s_suppkey = l_suppkey
223 | AND l_orderkey = o_orderkey
224 | AND o_custkey = c_custkey
225 | AND c_nationkey = n1.n_nationkey
226 | AND n1.n_regionkey = r_regionkey
227 | AND r_name = 'AMERICA'
228 | AND s_nationkey = n2.n_nationkey
229 | AND o_orderdate BETWEEN CAST('1995-01-01' AS date)
230 | AND CAST('1996-12-31' AS date)
231 | AND p_type = 'ECONOMY ANODIZED STEEL') AS all_nations
232 | GROUP BY
233 | o_year
234 | ORDER BY
235 | o_year;
236 | SELECT
237 | --Query09
238 | nation,
239 | o_year,
240 | SUM(amount) AS sum_profit
241 | FROM (
242 | SELECT
243 | n_name AS nation,
244 | EXTRACT(year
245 | FROM
246 | o_orderdate) AS o_year,
247 | l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity AS amount
248 | FROM
249 | part,
250 | supplier,
251 | lineitem,
252 | partsupp,
253 | orders,
254 | nation
255 | WHERE
256 | s_suppkey = l_suppkey
257 | AND ps_suppkey = l_suppkey
258 | AND ps_partkey = l_partkey
259 | AND p_partkey = l_partkey
260 | AND o_orderkey = l_orderkey
261 | AND s_nationkey = n_nationkey
262 | AND p_name LIKE '%green%') AS profit
263 | GROUP BY
264 | nation,
265 | o_year
266 | ORDER BY
267 | nation,
268 | o_year DESC;
269 | SELECT
270 | --Query10
271 | c_custkey,
272 | c_name,
273 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
274 | c_acctbal,
275 | n_name,
276 | c_address,
277 | c_phone,
278 | c_comment
279 | FROM
280 | customer,
281 | orders,
282 | lineitem,
283 | nation
284 | WHERE
285 | c_custkey = o_custkey
286 | AND l_orderkey = o_orderkey
287 | AND o_orderdate >= CAST('1993-10-01' AS date)
288 | AND o_orderdate < CAST('1994-01-01' AS date)
289 | AND l_returnflag = 'R'
290 | AND c_nationkey = n_nationkey
291 | GROUP BY
292 | c_custkey,
293 | c_name,
294 | c_acctbal,
295 | c_phone,
296 | n_name,
297 | c_address,
298 | c_comment
299 | ORDER BY
300 | revenue DESC
301 | LIMIT
302 | 20;
303 | SELECT
304 | --Query11
305 | ps_partkey,
306 | SUM(ps_supplycost * ps_availqty) AS value
307 | FROM
308 | partsupp,
309 | supplier,
310 | nation
311 | WHERE
312 | ps_suppkey = s_suppkey
313 | AND s_nationkey = n_nationkey
314 | AND n_name = 'GERMANY'
315 | GROUP BY
316 | ps_partkey
317 | HAVING
318 | SUM(ps_supplycost * ps_availqty) > (
319 | SELECT
320 | SUM(ps_supplycost * ps_availqty) * (0.0001/10)
321 | FROM
322 | partsupp,
323 | supplier,
324 | nation
325 | WHERE
326 | ps_suppkey = s_suppkey
327 | AND s_nationkey = n_nationkey
328 | AND n_name = 'GERMANY')
329 | ORDER BY
330 | value DESC;
331 | SELECT
332 | --Query12
333 | l_shipmode,
334 | SUM(
335 | CASE
336 | WHEN o_orderpriority = '1-URGENT' OR o_orderpriority = '2-HIGH' THEN 1
337 | ELSE
338 | 0
339 | END
340 | ) AS high_line_count,
341 | SUM(
342 | CASE
343 | WHEN o_orderpriority <> '1-URGENT' AND o_orderpriority <> '2-HIGH' THEN 1
344 | ELSE
345 | 0
346 | END
347 | ) AS low_line_count
348 | FROM
349 | orders,
350 | lineitem
351 | WHERE
352 | o_orderkey = l_orderkey
353 | AND l_shipmode IN ('MAIL',
354 | 'SHIP')
355 | AND l_commitdate < l_receiptdate
356 | AND l_shipdate < l_commitdate
357 | AND l_receiptdate >= CAST('1994-01-01' AS date)
358 | AND l_receiptdate < CAST('1995-01-01' AS date)
359 | GROUP BY
360 | l_shipmode
361 | ORDER BY
362 | l_shipmode;
363 | SELECT
364 | --Query13
365 | c_count,
366 | COUNT(*) AS custdist
367 | FROM (
368 | SELECT
369 | c_custkey,
370 | COUNT(o_orderkey) AS c_count
371 | FROM
372 | customer
373 | LEFT OUTER JOIN
374 | orders
375 | ON
376 | c_custkey = o_custkey
377 | AND o_comment NOT LIKE '%special%requests%'
378 | GROUP BY
379 | c_custkey) AS c_orders
380 | GROUP BY
381 | c_count
382 | ORDER BY
383 | custdist DESC,
384 | c_count DESC;
385 | SELECT
386 | --Query14
387 | 100.00 * SUM(
388 | CASE
389 | WHEN p_type LIKE 'PROMO%' THEN l_extendedprice * (1 - l_discount)
390 | ELSE
391 | 0
392 | END
393 | ) / SUM(l_extendedprice * (1 - l_discount)) AS promo_revenue
394 | FROM
395 | lineitem,
396 | part
397 | WHERE
398 | l_partkey = p_partkey
399 | AND l_shipdate >= date '1995-09-01'
400 | AND l_shipdate < CAST('1995-10-01' AS date);
401 | SELECT
402 | --Query15
403 | s_suppkey,
404 | s_name,
405 | s_address,
406 | s_phone,
407 | total_revenue
408 | FROM
409 | supplier,
410 | (
411 | SELECT
412 | l_suppkey AS supplier_no,
413 | SUM(l_extendedprice * (1 - l_discount)) AS total_revenue
414 | FROM
415 | lineitem
416 | WHERE
417 | l_shipdate >= CAST('1996-01-01' AS date)
418 | AND l_shipdate < CAST('1996-04-01' AS date)
419 | GROUP BY
420 | supplier_no) revenue0
421 | WHERE
422 | s_suppkey = supplier_no
423 | AND total_revenue = (
424 | SELECT
425 | MAX(total_revenue)
426 | FROM (
427 | SELECT
428 | l_suppkey AS supplier_no,
429 | SUM(l_extendedprice * (1 - l_discount)) AS total_revenue
430 | FROM
431 | lineitem
432 | WHERE
433 | l_shipdate >= CAST('1996-01-01' AS date)
434 | AND l_shipdate < CAST('1996-04-01' AS date)
435 | GROUP BY
436 | supplier_no) revenue1)
437 | ORDER BY
438 | s_suppkey;
439 | SELECT
440 | --Query16
441 | p_brand,
442 | p_type,
443 | p_size,
444 | COUNT(DISTINCT ps_suppkey) AS supplier_cnt
445 | FROM
446 | partsupp,
447 | part
448 | WHERE
449 | p_partkey = ps_partkey
450 | AND p_brand <> 'Brand#45'
451 | AND p_type NOT LIKE 'MEDIUM POLISHED%'
452 | AND p_size IN (49,
453 | 14,
454 | 23,
455 | 45,
456 | 19,
457 | 3,
458 | 36,
459 | 9)
460 | AND ps_suppkey NOT IN (
461 | SELECT
462 | s_suppkey
463 | FROM
464 | supplier
465 | WHERE
466 | s_comment LIKE '%Customer%Complaints%')
467 | GROUP BY
468 | p_brand,
469 | p_type,
470 | p_size
471 | ORDER BY
472 | supplier_cnt DESC,
473 | p_brand,
474 | p_type,
475 | p_size;
476 | SELECT
477 | --Query17
478 | SUM(l_extendedprice) / 7.0 AS avg_yearly
479 | FROM
480 | lineitem,
481 | part
482 | WHERE
483 | p_partkey = l_partkey
484 | AND p_brand = 'Brand#23'
485 | AND p_container = 'MED BOX'
486 | AND l_quantity < (
487 | SELECT
488 | 0.2 * AVG(l_quantity)
489 | FROM
490 | lineitem
491 | WHERE
492 | l_partkey = p_partkey);
493 | SELECT
494 | --Query18
495 | c_name,
496 | c_custkey,
497 | o_orderkey,
498 | o_orderdate,
499 | o_totalprice,
500 | SUM(l_quantity)
501 | FROM
502 | customer,
503 | orders,
504 | lineitem
505 | WHERE
506 | o_orderkey IN (
507 | SELECT
508 | l_orderkey
509 | FROM
510 | lineitem
511 | GROUP BY
512 | l_orderkey
513 | HAVING
514 | SUM(l_quantity) > 300)
515 | AND c_custkey = o_custkey
516 | AND o_orderkey = l_orderkey
517 | GROUP BY
518 | c_name,
519 | c_custkey,
520 | o_orderkey,
521 | o_orderdate,
522 | o_totalprice
523 | ORDER BY
524 | o_totalprice DESC,
525 | o_orderdate
526 | LIMIT
527 | 100;
528 | SELECT
529 | --Query19
530 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
531 | FROM
532 | lineitem,
533 | part
534 | WHERE
535 | (p_partkey = l_partkey
536 | AND p_brand = 'Brand#12'
537 | AND p_container IN ('SM CASE',
538 | 'SM BOX',
539 | 'SM PACK',
540 | 'SM PKG')
541 | AND l_quantity >= 1
542 | AND l_quantity <= 1 + 10
543 | AND p_size BETWEEN 1
544 | AND 5
545 | AND l_shipmode IN ('AIR',
546 | 'AIR REG')
547 | AND l_shipinstruct = 'DELIVER IN PERSON')
548 | OR (p_partkey = l_partkey
549 | AND p_brand = 'Brand#23'
550 | AND p_container IN ('MED BAG',
551 | 'MED BOX',
552 | 'MED PKG',
553 | 'MED PACK')
554 | AND l_quantity >= 10
555 | AND l_quantity <= 10 + 10
556 | AND p_size BETWEEN 1
557 | AND 10
558 | AND l_shipmode IN ('AIR',
559 | 'AIR REG')
560 | AND l_shipinstruct = 'DELIVER IN PERSON')
561 | OR (p_partkey = l_partkey
562 | AND p_brand = 'Brand#34'
563 | AND p_container IN ('LG CASE',
564 | 'LG BOX',
565 | 'LG PACK',
566 | 'LG PKG')
567 | AND l_quantity >= 20
568 | AND l_quantity <= 20 + 10
569 | AND p_size BETWEEN 1
570 | AND 15
571 | AND l_shipmode IN ('AIR',
572 | 'AIR REG')
573 | AND l_shipinstruct = 'DELIVER IN PERSON');
574 | SELECT
575 | --Query20
576 | s_name,
577 | s_address
578 | FROM
579 | supplier,
580 | nation
581 | WHERE
582 | s_suppkey IN (
583 | SELECT
584 | ps_suppkey
585 | FROM
586 | partsupp
587 | WHERE
588 | ps_partkey IN (
589 | SELECT
590 | p_partkey
591 | FROM
592 | part
593 | WHERE
594 | p_name LIKE 'forest%')
595 | AND ps_availqty > (
596 | SELECT
597 | 0.5 * SUM(l_quantity)
598 | FROM
599 | lineitem
600 | WHERE
601 | l_partkey = ps_partkey
602 | AND l_suppkey = ps_suppkey
603 | AND l_shipdate >= CAST('1994-01-01' AS date)
604 | AND l_shipdate < CAST('1995-01-01' AS date)))
605 | AND s_nationkey = n_nationkey
606 | AND n_name = 'CANADA'
607 | ORDER BY
608 | s_name;
609 | SELECT
610 | --Query21
611 | s_name,
612 | COUNT(*) AS numwait
613 | FROM
614 | supplier,
615 | lineitem l1,
616 | orders,
617 | nation
618 | WHERE
619 | s_suppkey = l1.l_suppkey
620 | AND o_orderkey = l1.l_orderkey
621 | AND o_orderstatus = 'F'
622 | AND l1.l_receiptdate > l1.l_commitdate
623 | AND EXISTS (
624 | SELECT
625 | *
626 | FROM
627 | lineitem l2
628 | WHERE
629 | l2.l_orderkey = l1.l_orderkey
630 | AND l2.l_suppkey <> l1.l_suppkey)
631 | AND NOT EXISTS (
632 | SELECT
633 | *
634 | FROM
635 | lineitem l3
636 | WHERE
637 | l3.l_orderkey = l1.l_orderkey
638 | AND l3.l_suppkey <> l1.l_suppkey
639 | AND l3.l_receiptdate > l3.l_commitdate)
640 | AND s_nationkey = n_nationkey
641 | AND n_name = 'SAUDI ARABIA'
642 | GROUP BY
643 | s_name
644 | ORDER BY
645 | numwait DESC,
646 | s_name
647 | LIMIT
648 | 100;
649 | SELECT
650 | --Query22
651 | cntrycode,
652 | COUNT(*) AS numcust,
653 | SUM(c_acctbal) AS totacctbal
654 | FROM (
655 | SELECT
656 | SUBSTRING(c_phone, 1, 2) AS cntrycode,
657 | c_acctbal
658 | FROM
659 | customer
660 | WHERE
661 | SUBSTRING(c_phone, 1, 2) IN ('13',
662 | '31',
663 | '23',
664 | '29',
665 | '30',
666 | '18',
667 | '17')
668 | AND c_acctbal > (
669 | SELECT
670 | AVG(c_acctbal)
671 | FROM
672 | customer
673 | WHERE
674 | c_acctbal > 0.00
675 | AND SUBSTRING(c_phone, 1, 2) IN ('13',
676 | '31',
677 | '23',
678 | '29',
679 | '30',
680 | '18',
681 | '17'))
682 | AND NOT EXISTS (
683 | SELECT
684 | *
685 | FROM
686 | orders
687 | WHERE
688 | o_custkey = c_custkey)) AS custsale
689 | GROUP BY
690 | cntrycode
691 | ORDER BY
692 | cntrycode;
693 |
--------------------------------------------------------------------------------
/Database/trino.sql:
--------------------------------------------------------------------------------
1 | -- Changed Query 15
2 |
3 |
4 | SELECT
5 | --Query01
6 | l_returnflag,
7 | l_linestatus,
8 | SUM(l_quantity) AS sum_qty,
9 | SUM(l_extendedprice) AS sum_base_price,
10 | SUM(l_extendedprice * (1 - l_discount)) AS sum_disc_price,
11 | SUM(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge,
12 | AVG(l_quantity) AS avg_qty,
13 | AVG(l_extendedprice) AS avg_price,
14 | AVG(l_discount) AS avg_disc,
15 | COUNT(*) AS count_order
16 | FROM
17 | lineitem
18 | WHERE
19 | l_shipdate <= CAST('1998-09-02' AS date)
20 | GROUP BY
21 | l_returnflag,
22 | l_linestatus
23 | ORDER BY
24 | l_returnflag,
25 | l_linestatus;
26 | SELECT
27 | --Query02
28 | s_acctbal,
29 | s_name,
30 | n_name,
31 | p_partkey,
32 | p_mfgr,
33 | s_address,
34 | s_phone,
35 | s_comment
36 | FROM
37 | part,
38 | supplier,
39 | partsupp,
40 | nation,
41 | region
42 | WHERE
43 | p_partkey = ps_partkey
44 | AND s_suppkey = ps_suppkey
45 | AND p_size = 15
46 | AND p_type LIKE '%BRASS'
47 | AND s_nationkey = n_nationkey
48 | AND n_regionkey = r_regionkey
49 | AND r_name = 'EUROPE'
50 | AND ps_supplycost = (
51 | SELECT
52 | MIN(ps_supplycost)
53 | FROM
54 | partsupp,
55 | supplier,
56 | nation,
57 | region
58 | WHERE
59 | p_partkey = ps_partkey
60 | AND s_suppkey = ps_suppkey
61 | AND s_nationkey = n_nationkey
62 | AND n_regionkey = r_regionkey
63 | AND r_name = 'EUROPE'
64 | )
65 | ORDER BY
66 | s_acctbal DESC,
67 | n_name,
68 | s_name,
69 | p_partkey
70 | LIMIT
71 | 100;
72 | SELECT
73 | --Query03
74 | l_orderkey,
75 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
76 | o_orderdate,
77 | o_shippriority
78 | FROM
79 | customer,
80 | orders,
81 | lineitem
82 | WHERE
83 | c_mktsegment = 'BUILDING'
84 | AND c_custkey = o_custkey
85 | AND l_orderkey = o_orderkey
86 | AND o_orderdate < CAST('1995-03-15' AS date)
87 | AND l_shipdate > CAST('1995-03-15' AS date)
88 | GROUP BY
89 | l_orderkey,
90 | o_orderdate,
91 | o_shippriority
92 | ORDER BY
93 | revenue DESC,
94 | o_orderdate
95 | LIMIT
96 | 10;
97 | SELECT
98 | --Query04
99 | o_orderpriority,
100 | COUNT(*) AS order_count
101 | FROM
102 | orders
103 | WHERE
104 | o_orderdate >= CAST('1993-07-01' AS date)
105 | AND o_orderdate < CAST('1993-10-01' AS date)
106 | AND EXISTS (
107 | SELECT
108 | *
109 | FROM
110 | lineitem
111 | WHERE
112 | l_orderkey = o_orderkey
113 | AND l_commitdate < l_receiptdate
114 | )
115 | GROUP BY
116 | o_orderpriority
117 | ORDER BY
118 | o_orderpriority;
119 | SELECT
120 | --Query05
121 | n_name,
122 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
123 | FROM
124 | customer,
125 | orders,
126 | lineitem,
127 | supplier,
128 | nation,
129 | region
130 | WHERE
131 | c_custkey = o_custkey
132 | AND l_orderkey = o_orderkey
133 | AND l_suppkey = s_suppkey
134 | AND c_nationkey = s_nationkey
135 | AND s_nationkey = n_nationkey
136 | AND n_regionkey = r_regionkey
137 | AND r_name = 'ASIA'
138 | AND o_orderdate >= CAST('1994-01-01' AS date)
139 | AND o_orderdate < CAST('1995-01-01' AS date)
140 | GROUP BY
141 | n_name
142 | ORDER BY
143 | revenue DESC;
144 | SELECT
145 | --Query06
146 | SUM(l_extendedprice * l_discount) AS revenue
147 | FROM
148 | lineitem
149 | WHERE
150 | l_shipdate >= CAST('1994-01-01' AS date)
151 | AND l_shipdate < CAST('1995-01-01' AS date)
152 | AND l_discount BETWEEN 0.05
153 | AND 0.07
154 | AND l_quantity < 24;
155 | SELECT
156 | --Query07
157 | supp_nation,
158 | cust_nation,
159 | l_year,
160 | SUM(volume) AS revenue
161 | FROM
162 | (
163 | SELECT
164 | n1.n_name AS supp_nation,
165 | n2.n_name AS cust_nation,
166 | EXTRACT(
167 | year
168 | FROM
169 | l_shipdate
170 | ) AS l_year,
171 | l_extendedprice * (1 - l_discount) AS volume
172 | FROM
173 | supplier,
174 | lineitem,
175 | orders,
176 | customer,
177 | nation n1,
178 | nation n2
179 | WHERE
180 | s_suppkey = l_suppkey
181 | AND o_orderkey = l_orderkey
182 | AND c_custkey = o_custkey
183 | AND s_nationkey = n1.n_nationkey
184 | AND c_nationkey = n2.n_nationkey
185 | AND (
186 | (
187 | n1.n_name = 'FRANCE'
188 | AND n2.n_name = 'GERMANY'
189 | )
190 | OR (
191 | n1.n_name = 'GERMANY'
192 | AND n2.n_name = 'FRANCE'
193 | )
194 | )
195 | AND l_shipdate BETWEEN CAST('1995-01-01' AS date)
196 | AND CAST('1996-12-31' AS date)
197 | ) AS shipping
198 | GROUP BY
199 | supp_nation,
200 | cust_nation,
201 | l_year
202 | ORDER BY
203 | supp_nation,
204 | cust_nation,
205 | l_year;
206 | SELECT
207 | --Query08
208 | o_year,
209 | SUM(
210 | CASE
211 | WHEN nation = 'BRAZIL' THEN volume
212 | ELSE 0
213 | END
214 | ) / SUM(volume) AS mkt_share
215 | FROM
216 | (
217 | SELECT
218 | EXTRACT(
219 | year
220 | FROM
221 | o_orderdate
222 | ) AS o_year,
223 | l_extendedprice * (1 - l_discount) AS volume,
224 | n2.n_name AS nation
225 | FROM
226 | part,
227 | supplier,
228 | lineitem,
229 | orders,
230 | customer,
231 | nation n1,
232 | nation n2,
233 | region
234 | WHERE
235 | p_partkey = l_partkey
236 | AND s_suppkey = l_suppkey
237 | AND l_orderkey = o_orderkey
238 | AND o_custkey = c_custkey
239 | AND c_nationkey = n1.n_nationkey
240 | AND n1.n_regionkey = r_regionkey
241 | AND r_name = 'AMERICA'
242 | AND s_nationkey = n2.n_nationkey
243 | AND o_orderdate BETWEEN CAST('1995-01-01' AS date)
244 | AND CAST('1996-12-31' AS date)
245 | AND p_type = 'ECONOMY ANODIZED STEEL'
246 | ) AS all_nations
247 | GROUP BY
248 | o_year
249 | ORDER BY
250 | o_year;
251 | SELECT
252 | --Query09
253 | nation,
254 | o_year,
255 | SUM(amount) AS sum_profit
256 | FROM
257 | (
258 | SELECT
259 | n_name AS nation,
260 | EXTRACT(
261 | year
262 | FROM
263 | o_orderdate
264 | ) AS o_year,
265 | l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity AS amount
266 | FROM
267 | part,
268 | supplier,
269 | lineitem,
270 | partsupp,
271 | orders,
272 | nation
273 | WHERE
274 | s_suppkey = l_suppkey
275 | AND ps_suppkey = l_suppkey
276 | AND ps_partkey = l_partkey
277 | AND p_partkey = l_partkey
278 | AND o_orderkey = l_orderkey
279 | AND s_nationkey = n_nationkey
280 | AND p_name LIKE '%green%'
281 | ) AS profit
282 | GROUP BY
283 | nation,
284 | o_year
285 | ORDER BY
286 | nation,
287 | o_year DESC;
288 | SELECT
289 | --Query10
290 | c_custkey,
291 | c_name,
292 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
293 | c_acctbal,
294 | n_name,
295 | c_address,
296 | c_phone,
297 | c_comment
298 | FROM
299 | customer,
300 | orders,
301 | lineitem,
302 | nation
303 | WHERE
304 | c_custkey = o_custkey
305 | AND l_orderkey = o_orderkey
306 | AND o_orderdate >= CAST('1993-10-01' AS date)
307 | AND o_orderdate < CAST('1994-01-01' AS date)
308 | AND l_returnflag = 'R'
309 | AND c_nationkey = n_nationkey
310 | GROUP BY
311 | c_custkey,
312 | c_name,
313 | c_acctbal,
314 | c_phone,
315 | n_name,
316 | c_address,
317 | c_comment
318 | ORDER BY
319 | revenue DESC
320 | LIMIT
321 | 20;
322 | SELECT
323 | --Query11
324 | ps_partkey,
325 | SUM(ps_supplycost * ps_availqty) AS value
326 | FROM
327 | partsupp,
328 | supplier,
329 | nation
330 | WHERE
331 | ps_suppkey = s_suppkey
332 | AND s_nationkey = n_nationkey
333 | AND n_name = 'GERMANY'
334 | GROUP BY
335 | ps_partkey
336 | HAVING
337 | SUM(ps_supplycost * ps_availqty) > (
338 | SELECT
339 | SUM(ps_supplycost * ps_availqty) * (0.0001/10)
340 | -- SUM(ps_supplycost * ps_availqty) * 1
341 | FROM
342 | partsupp,
343 | supplier,
344 | nation
345 | WHERE
346 | ps_suppkey = s_suppkey
347 | AND s_nationkey = n_nationkey
348 | AND n_name = 'GERMANY'
349 | )
350 | ORDER BY
351 | value DESC;
352 |
353 |
354 |
355 | SELECT
356 | --Query12
357 | l_shipmode,
358 | SUM(
359 | CASE
360 | WHEN o_orderpriority = '1-URGENT'
361 | OR o_orderpriority = '2-HIGH' THEN 1
362 | ELSE 0
363 | END
364 | ) AS high_line_count,
365 | SUM(
366 | CASE
367 | WHEN o_orderpriority <> '1-URGENT'
368 | AND o_orderpriority <> '2-HIGH' THEN 1
369 | ELSE 0
370 | END
371 | ) AS low_line_count
372 | FROM
373 | orders,
374 | lineitem
375 | WHERE
376 | o_orderkey = l_orderkey
377 | AND l_shipmode IN ('MAIL', 'SHIP')
378 | AND l_commitdate < l_receiptdate
379 | AND l_shipdate < l_commitdate
380 | AND l_receiptdate >= CAST('1994-01-01' AS date)
381 | AND l_receiptdate < CAST('1995-01-01' AS date)
382 | GROUP BY
383 | l_shipmode
384 | ORDER BY
385 | l_shipmode;
386 | SELECT
387 | --Query13
388 | c_count,
389 | COUNT(*) AS custdist
390 | FROM
391 | (
392 | SELECT
393 | c_custkey,
394 | COUNT(o_orderkey) AS c_count
395 | FROM
396 | customer
397 | LEFT OUTER JOIN orders ON c_custkey = o_custkey
398 | AND o_comment NOT LIKE '%special%requests%'
399 | GROUP BY
400 | c_custkey
401 | ) AS c_orders
402 | GROUP BY
403 | c_count
404 | ORDER BY
405 | custdist DESC,
406 | c_count DESC;
407 | SELECT
408 | --Query14
409 | 100.00 * SUM(
410 | CASE
411 | WHEN p_type LIKE 'PROMO%' THEN l_extendedprice * (1 - l_discount)
412 | ELSE 0
413 | END
414 | ) / SUM(l_extendedprice * (1 - l_discount)) AS promo_revenue
415 | FROM
416 | lineitem,
417 | part
418 | WHERE
419 | l_partkey = p_partkey
420 | AND l_shipdate >= date '1995-09-01'
421 | AND l_shipdate < CAST('1995-10-01' AS date);
422 |
423 |
424 |
425 |
426 | with revenue (supplier_no, total_revenue) as (
427 | --Query15
428 | select
429 | l_suppkey,
430 | sum(l_extendedprice * (1 - l_discount))
431 | from
432 | lineitem
433 | where
434 | l_shipdate >= date '1996-01-01'
435 | and l_shipdate < date '1996-01-01' + interval '3' month
436 | group by
437 | l_suppkey)
438 | select
439 | s_suppkey,
440 | s_name,
441 | s_address,
442 | s_phone,
443 | total_revenue
444 | from
445 | supplier,
446 | revenue
447 | where
448 | s_suppkey = supplier_no
449 | and total_revenue = (
450 | select
451 | max(total_revenue)
452 | from
453 | revenue
454 | )
455 | order by
456 | s_suppkey;
457 | SELECT
458 | --Query16
459 | p_brand,
460 | p_type,
461 | p_size,
462 | COUNT(DISTINCT ps_suppkey) AS supplier_cnt
463 | FROM
464 | partsupp,
465 | part
466 | WHERE
467 | p_partkey = ps_partkey
468 | AND p_brand <> 'Brand#45'
469 | AND p_type NOT LIKE 'MEDIUM POLISHED%'
470 | AND p_size IN (
471 | 49,
472 | 14,
473 | 23,
474 | 45,
475 | 19,
476 | 3,
477 | 36,
478 | 9
479 | )
480 | AND ps_suppkey NOT IN (
481 | SELECT
482 | s_suppkey
483 | FROM
484 | supplier
485 | WHERE
486 | s_comment LIKE '%Customer%Complaints%'
487 | )
488 | GROUP BY
489 | p_brand,
490 | p_type,
491 | p_size
492 | ORDER BY
493 | supplier_cnt DESC,
494 | p_brand,
495 | p_type,
496 | p_size;
497 | SELECT
498 | --Query17
499 | SUM(l_extendedprice) / 7.0 AS avg_yearly
500 | FROM
501 | lineitem,
502 | part
503 | WHERE
504 | p_partkey = l_partkey
505 | AND p_brand = 'Brand#23'
506 | AND p_container = 'MED BOX'
507 | AND l_quantity < (
508 | SELECT
509 | 0.2 * AVG(l_quantity)
510 | FROM
511 | lineitem
512 | WHERE
513 | l_partkey = p_partkey
514 | );
515 | SELECT
516 | --Query18
517 | c_name,
518 | c_custkey,
519 | o_orderkey,
520 | o_orderdate,
521 | o_totalprice,
522 | SUM(l_quantity)
523 | FROM
524 | customer,
525 | orders,
526 | lineitem
527 | WHERE
528 | o_orderkey IN (
529 | SELECT
530 | l_orderkey
531 | FROM
532 | lineitem
533 | GROUP BY
534 | l_orderkey
535 | HAVING
536 | SUM(l_quantity) > 300
537 | )
538 | AND c_custkey = o_custkey
539 | AND o_orderkey = l_orderkey
540 | GROUP BY
541 | c_name,
542 | c_custkey,
543 | o_orderkey,
544 | o_orderdate,
545 | o_totalprice
546 | ORDER BY
547 | o_totalprice DESC,
548 | o_orderdate
549 | LIMIT
550 | 100;
551 | SELECT
552 | --Query19
553 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
554 | FROM
555 | lineitem,
556 | part
557 | WHERE
558 | (
559 | p_partkey = l_partkey
560 | AND p_brand = 'Brand#12'
561 | AND p_container IN (
562 | 'SM CASE',
563 | 'SM BOX',
564 | 'SM PACK',
565 | 'SM PKG'
566 | )
567 | AND l_quantity >= 1
568 | AND l_quantity <= 1 + 10
569 | AND p_size BETWEEN 1
570 | AND 5
571 | AND l_shipmode IN ('AIR', 'AIR REG')
572 | AND l_shipinstruct = 'DELIVER IN PERSON'
573 | )
574 | OR (
575 | p_partkey = l_partkey
576 | AND p_brand = 'Brand#23'
577 | AND p_container IN (
578 | 'MED BAG',
579 | 'MED BOX',
580 | 'MED PKG',
581 | 'MED PACK'
582 | )
583 | AND l_quantity >= 10
584 | AND l_quantity <= 10 + 10
585 | AND p_size BETWEEN 1
586 | AND 10
587 | AND l_shipmode IN ('AIR', 'AIR REG')
588 | AND l_shipinstruct = 'DELIVER IN PERSON'
589 | )
590 | OR (
591 | p_partkey = l_partkey
592 | AND p_brand = 'Brand#34'
593 | AND p_container IN (
594 | 'LG CASE',
595 | 'LG BOX',
596 | 'LG PACK',
597 | 'LG PKG'
598 | )
599 | AND l_quantity >= 20
600 | AND l_quantity <= 20 + 10
601 | AND p_size BETWEEN 1
602 | AND 15
603 | AND l_shipmode IN ('AIR', 'AIR REG')
604 | AND l_shipinstruct = 'DELIVER IN PERSON'
605 | );
606 | SELECT
607 | --Query20
608 | s_name,
609 | s_address
610 | FROM
611 | supplier,
612 | nation
613 | WHERE
614 | s_suppkey IN (
615 | SELECT
616 | ps_suppkey
617 | FROM
618 | partsupp
619 | WHERE
620 | ps_partkey IN (
621 | SELECT
622 | p_partkey
623 | FROM
624 | part
625 | WHERE
626 | p_name LIKE 'forest%'
627 | )
628 | AND ps_availqty > (
629 | SELECT
630 | 0.5 * SUM(l_quantity)
631 | FROM
632 | lineitem
633 | WHERE
634 | l_partkey = ps_partkey
635 | AND l_suppkey = ps_suppkey
636 | AND l_shipdate >= CAST('1994-01-01' AS date)
637 | AND l_shipdate < CAST('1995-01-01' AS date)
638 | )
639 | )
640 | AND s_nationkey = n_nationkey
641 | AND n_name = 'CANADA'
642 | ORDER BY
643 | s_name;
644 | SELECT
645 | --Query21
646 | s_name,
647 | COUNT(*) AS numwait
648 | FROM
649 | supplier,
650 | lineitem l1,
651 | orders,
652 | nation
653 | WHERE
654 | s_suppkey = l1.l_suppkey
655 | AND o_orderkey = l1.l_orderkey
656 | AND o_orderstatus = 'F'
657 | AND l1.l_receiptdate > l1.l_commitdate
658 | AND EXISTS (
659 | SELECT
660 | *
661 | FROM
662 | lineitem l2
663 | WHERE
664 | l2.l_orderkey = l1.l_orderkey
665 | AND l2.l_suppkey <> l1.l_suppkey
666 | )
667 | AND NOT EXISTS (
668 | SELECT
669 | *
670 | FROM
671 | lineitem l3
672 | WHERE
673 | l3.l_orderkey = l1.l_orderkey
674 | AND l3.l_suppkey <> l1.l_suppkey
675 | AND l3.l_receiptdate > l3.l_commitdate
676 | )
677 | AND s_nationkey = n_nationkey
678 | AND n_name = 'SAUDI ARABIA'
679 | GROUP BY
680 | s_name
681 | ORDER BY
682 | numwait DESC,
683 | s_name
684 | LIMIT
685 | 100;
686 | SELECT
687 | --Query22
688 | cntrycode,
689 | COUNT(*) AS numcust,
690 | SUM(c_acctbal) AS totacctbal
691 | FROM
692 | (
693 | SELECT
694 | SUBSTRING(c_phone, 1, 2) AS cntrycode,
695 | c_acctbal
696 | FROM
697 | customer
698 | WHERE
699 | SUBSTRING(c_phone, 1, 2) IN (
700 | '13',
701 | '31',
702 | '23',
703 | '29',
704 | '30',
705 | '18',
706 | '17'
707 | )
708 | AND c_acctbal > (
709 | SELECT
710 | AVG(c_acctbal)
711 | FROM
712 | customer
713 | WHERE
714 | c_acctbal > 0.00
715 | AND SUBSTRING(c_phone, 1, 2) IN (
716 | '13',
717 | '31',
718 | '23',
719 | '29',
720 | '30',
721 | '18',
722 | '17'
723 | )
724 | )
725 | AND NOT EXISTS (
726 | SELECT
727 | *
728 | FROM
729 | orders
730 | WHERE
731 | o_custkey = c_custkey
732 | )
733 | ) AS custsale
734 | GROUP BY
735 | cntrycode
736 | ORDER BY
737 | cntrycode;
738 |
--------------------------------------------------------------------------------
/Database/Synapse_serverless.sql:
--------------------------------------------------------------------------------
1 | -- T-SQL
2 | SELECT
3 | --Query01
4 | l_returnflag,
5 | l_linestatus,
6 | SUM(l_quantity) AS sum_qty,
7 | SUM(l_extendedprice) AS sum_base_price,
8 | SUM(l_extendedprice * (1 - l_discount)) AS sum_disc_price,
9 | SUM(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge,
10 | AVG(l_quantity) AS avg_qty,
11 | AVG(l_extendedprice) AS avg_price,
12 | AVG(l_discount) AS avg_disc,
13 | COUNT(*) AS count_order
14 | FROM
15 | lineitem
16 | WHERE
17 | l_shipdate <= CAST('1998-09-02' AS date)
18 | GROUP BY
19 | l_returnflag,
20 | l_linestatus
21 | ORDER BY
22 | l_returnflag,
23 | l_linestatus;
24 |
25 |
26 | SELECT
27 | --Query02
28 | top 100
29 | s_acctbal,
30 | s_name,
31 | n_name,
32 | p_partkey,
33 | p_mfgr,
34 | s_address,
35 | s_phone,
36 | s_comment
37 | FROM
38 | part,
39 | supplier,
40 | partsupp,
41 | nation,
42 | region
43 | WHERE
44 | p_partkey = ps_partkey
45 | AND s_suppkey = ps_suppkey
46 | AND p_size = 15
47 | AND p_type LIKE '%BRASS'
48 | AND s_nationkey = n_nationkey
49 | AND n_regionkey = r_regionkey
50 | AND r_name = 'EUROPE'
51 | AND ps_supplycost = (
52 | SELECT
53 | MIN(ps_supplycost)
54 | FROM
55 | partsupp,
56 | supplier,
57 | nation,
58 | region
59 | WHERE
60 | p_partkey = ps_partkey
61 | AND s_suppkey = ps_suppkey
62 | AND s_nationkey = n_nationkey
63 | AND n_regionkey = r_regionkey
64 | AND r_name = 'EUROPE'
65 | )
66 | ORDER BY
67 | s_acctbal DESC,
68 | n_name,
69 | s_name,
70 | p_partkey ;
71 |
72 |
73 | SELECT
74 | --Query03
75 | top 10
76 | l_orderkey,
77 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
78 | o_orderdate,
79 | o_shippriority
80 | FROM
81 | customer,
82 | orders,
83 | lineitem
84 | WHERE
85 | c_mktsegment = 'BUILDING'
86 | AND c_custkey = o_custkey
87 | AND l_orderkey = o_orderkey
88 | AND o_orderdate < CAST('1995-03-15' AS date)
89 | AND l_shipdate > CAST('1995-03-15' AS date)
90 | GROUP BY
91 | l_orderkey,
92 | o_orderdate,
93 | o_shippriority
94 | ORDER BY
95 | revenue DESC,
96 | o_orderdate ;
97 |
98 |
99 |
100 |
101 | SELECT
102 | --Query04
103 | o_orderpriority,
104 | COUNT(*) AS order_count
105 | FROM
106 | orders
107 | WHERE
108 | o_orderdate >= CAST('1993-07-01' AS date)
109 | AND o_orderdate < CAST('1993-10-01' AS date)
110 | AND EXISTS (
111 | SELECT
112 | *
113 | FROM
114 | lineitem
115 | WHERE
116 | l_orderkey = o_orderkey
117 | AND l_commitdate < l_receiptdate
118 | )
119 | GROUP BY
120 | o_orderpriority
121 | ORDER BY
122 | o_orderpriority;
123 |
124 |
125 | SELECT
126 | --Query05
127 | n_name,
128 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
129 | FROM
130 | customer,
131 | orders,
132 | lineitem,
133 | supplier,
134 | nation,
135 | region
136 | WHERE
137 | c_custkey = o_custkey
138 | AND l_orderkey = o_orderkey
139 | AND l_suppkey = s_suppkey
140 | AND c_nationkey = s_nationkey
141 | AND s_nationkey = n_nationkey
142 | AND n_regionkey = r_regionkey
143 | AND r_name = 'ASIA'
144 | AND o_orderdate >= CAST('1994-01-01' AS date)
145 | AND o_orderdate < CAST('1995-01-01' AS date)
146 | GROUP BY
147 | n_name
148 | ORDER BY
149 | revenue DESC;
150 |
151 |
152 |
153 | SELECT
154 | --Query06
155 | SUM(l_extendedprice * l_discount) AS revenue
156 | FROM
157 | lineitem
158 | WHERE
159 | l_shipdate >= CAST('1994-01-01' AS date)
160 | AND l_shipdate < CAST('1995-01-01' AS date)
161 | AND l_discount BETWEEN 0.05
162 | AND 0.07
163 | AND l_quantity < 24;
164 |
165 |
166 | SELECT
167 | --Query07
168 | supp_nation,
169 | cust_nation,
170 | l_year,
171 | SUM(volume) AS revenue
172 | FROM
173 | (
174 | SELECT
175 | n1.n_name AS supp_nation,
176 | n2.n_name AS cust_nation,
177 | YEAR(
178 | l_shipdate
179 | ) AS l_year,
180 | l_extendedprice * (1 - l_discount) AS volume
181 | FROM
182 | supplier,
183 | lineitem,
184 | orders,
185 | customer,
186 | nation n1,
187 | nation n2
188 | WHERE
189 | s_suppkey = l_suppkey
190 | AND o_orderkey = l_orderkey
191 | AND c_custkey = o_custkey
192 | AND s_nationkey = n1.n_nationkey
193 | AND c_nationkey = n2.n_nationkey
194 | AND (
195 | (
196 | n1.n_name = 'FRANCE'
197 | AND n2.n_name = 'GERMANY'
198 | )
199 | OR (
200 | n1.n_name = 'GERMANY'
201 | AND n2.n_name = 'FRANCE'
202 | )
203 | )
204 | AND l_shipdate BETWEEN CAST('1995-01-01' AS date)
205 | AND CAST('1996-12-31' AS date)
206 | ) AS shipping
207 | GROUP BY
208 | supp_nation,
209 | cust_nation,
210 | l_year
211 | ORDER BY
212 | supp_nation,
213 | cust_nation,
214 | l_year;
215 |
216 |
217 | SELECT
218 | --Query08
219 | o_year,
220 | SUM(
221 | CASE
222 | WHEN nation = 'BRAZIL' THEN volume
223 | ELSE 0
224 | END
225 | ) / SUM(volume) AS mkt_share
226 | FROM
227 | (
228 | SELECT
229 |
230 | year (
231 | o_orderdate
232 | ) AS o_year,
233 | l_extendedprice * (1 - l_discount) AS volume,
234 | n2.n_name AS nation
235 | FROM
236 | part,
237 | supplier,
238 | lineitem,
239 | orders,
240 | customer,
241 | nation n1,
242 | nation n2,
243 | region
244 | WHERE
245 | p_partkey = l_partkey
246 | AND s_suppkey = l_suppkey
247 | AND l_orderkey = o_orderkey
248 | AND o_custkey = c_custkey
249 | AND c_nationkey = n1.n_nationkey
250 | AND n1.n_regionkey = r_regionkey
251 | AND r_name = 'AMERICA'
252 | AND s_nationkey = n2.n_nationkey
253 | AND o_orderdate BETWEEN CAST('1995-01-01' AS date)
254 | AND CAST('1996-12-31' AS date)
255 | AND p_type = 'ECONOMY ANODIZED STEEL'
256 | ) AS all_nations
257 | GROUP BY
258 | o_year
259 | ORDER BY
260 | o_year;
261 |
262 |
263 | SELECT
264 | --Query09
265 | nation,
266 | o_year,
267 | SUM(amount) AS sum_profit
268 | FROM
269 | (
270 | SELECT
271 | n_name AS nation,
272 |
273 | year (
274 |
275 | o_orderdate
276 | ) AS o_year,
277 | l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity AS amount
278 | FROM
279 | part,
280 | supplier,
281 | lineitem,
282 | partsupp,
283 | orders,
284 | nation
285 | WHERE
286 | s_suppkey = l_suppkey
287 | AND ps_suppkey = l_suppkey
288 | AND ps_partkey = l_partkey
289 | AND p_partkey = l_partkey
290 | AND o_orderkey = l_orderkey
291 | AND s_nationkey = n_nationkey
292 | AND p_name LIKE '%green%'
293 | ) AS profit
294 | GROUP BY
295 | nation,
296 | o_year
297 | ORDER BY
298 | nation,
299 | o_year DESC;
300 |
301 |
302 | SELECT
303 | --Query10
304 | top 20
305 | c_custkey,
306 | c_name,
307 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
308 | c_acctbal,
309 | n_name,
310 | c_address,
311 | c_phone,
312 | c_comment
313 | FROM
314 | customer,
315 | orders,
316 | lineitem,
317 | nation
318 | WHERE
319 | c_custkey = o_custkey
320 | AND l_orderkey = o_orderkey
321 | AND o_orderdate >= CAST('1993-10-01' AS date)
322 | AND o_orderdate < CAST('1994-01-01' AS date)
323 | AND l_returnflag = 'R'
324 | AND c_nationkey = n_nationkey
325 | GROUP BY
326 | c_custkey,
327 | c_name,
328 | c_acctbal,
329 | c_phone,
330 | n_name,
331 | c_address,
332 | c_comment
333 | ORDER BY
334 | revenue DESC;
335 |
336 |
337 | SELECT
338 | --Query11
339 | ps_partkey,
340 | SUM(ps_supplycost * ps_availqty) AS value
341 | FROM
342 | partsupp,
343 | supplier,
344 | nation
345 | WHERE
346 | ps_suppkey = s_suppkey
347 | AND s_nationkey = n_nationkey
348 | AND n_name = 'GERMANY'
349 | GROUP BY
350 | ps_partkey
351 | HAVING
352 | SUM(ps_supplycost * ps_availqty) > (
353 | SELECT
354 | SUM(ps_supplycost * ps_availqty) * (0.0001/10)
355 | -- SUM(ps_supplycost * ps_availqty) * 1
356 | FROM
357 | partsupp,
358 | supplier,
359 | nation
360 | WHERE
361 | ps_suppkey = s_suppkey
362 | AND s_nationkey = n_nationkey
363 | AND n_name = 'GERMANY'
364 | )
365 | ORDER BY
366 | value DESC;
367 |
368 |
369 |
370 | SELECT
371 | --Query12
372 | l_shipmode,
373 | SUM(
374 | CASE
375 | WHEN o_orderpriority = '1-URGENT'
376 | OR o_orderpriority = '2-HIGH' THEN 1
377 | ELSE 0
378 | END
379 | ) AS high_line_count,
380 | SUM(
381 | CASE
382 | WHEN o_orderpriority <> '1-URGENT'
383 | AND o_orderpriority <> '2-HIGH' THEN 1
384 | ELSE 0
385 | END
386 | ) AS low_line_count
387 | FROM
388 | orders,
389 | lineitem
390 | WHERE
391 | o_orderkey = l_orderkey
392 | AND l_shipmode IN ('MAIL', 'SHIP')
393 | AND l_commitdate < l_receiptdate
394 | AND l_shipdate < l_commitdate
395 | AND l_receiptdate >= CAST('1994-01-01' AS date)
396 | AND l_receiptdate < CAST('1995-01-01' AS date)
397 | GROUP BY
398 | l_shipmode
399 | ORDER BY
400 | l_shipmode;
401 |
402 |
403 | SELECT
404 | --Query13
405 | c_count,
406 | COUNT(*) AS custdist
407 | FROM
408 | (
409 | SELECT
410 | c_custkey,
411 | COUNT(o_orderkey) AS c_count
412 | FROM
413 | customer
414 | LEFT OUTER JOIN orders ON c_custkey = o_custkey
415 | AND o_comment NOT LIKE '%special%requests%'
416 | GROUP BY
417 | c_custkey
418 | ) AS c_orders
419 | GROUP BY
420 | c_count
421 | ORDER BY
422 | custdist DESC,
423 | c_count DESC;
424 |
425 |
426 | SELECT
427 | --Query14
428 | 100.00 * SUM(
429 | CASE
430 | WHEN p_type LIKE 'PROMO%' THEN l_extendedprice * (1 - l_discount)
431 | ELSE 0
432 | END
433 | ) / SUM(l_extendedprice * (1 - l_discount)) AS promo_revenue
434 | FROM
435 | lineitem,
436 | part
437 | WHERE
438 | l_partkey = p_partkey AND l_shipdate >= cast( '1995-09-01' as date) AND l_shipdate < CAST('1995-10-01' AS date);
439 |
440 | SELECT
441 | --Query15
442 | s_suppkey,
443 | s_name,
444 | s_address,
445 | s_phone,
446 | total_revenue
447 | FROM
448 | supplier,
449 | (
450 | SELECT
451 | l_suppkey AS supplier_no,
452 | SUM(l_extendedprice * (1 - l_discount)) AS total_revenue
453 | FROM
454 | lineitem
455 | WHERE
456 | l_shipdate >= CAST('1996-01-01' AS date)
457 | AND l_shipdate < CAST('1996-04-01' AS date)
458 | GROUP BY
459 | l_suppkey
460 | ) revenue0
461 | WHERE
462 | s_suppkey = supplier_no
463 | AND total_revenue = (
464 | SELECT
465 | MAX(total_revenue)
466 | FROM
467 | (
468 | SELECT
469 | l_suppkey AS supplier_no,
470 | SUM(l_extendedprice * (1 - l_discount)) AS total_revenue
471 | FROM
472 | lineitem
473 | WHERE
474 | l_shipdate >= CAST('1996-01-01' AS date)
475 | AND l_shipdate < CAST('1996-04-01' AS date)
476 | GROUP BY
477 | l_suppkey
478 | ) revenue1
479 | )
480 | ORDER BY
481 | s_suppkey;
482 |
483 |
484 | SELECT
485 | --Query16
486 | p_brand,
487 | p_type,
488 | p_size,
489 | COUNT(DISTINCT ps_suppkey) AS supplier_cnt
490 | FROM
491 | partsupp,
492 | part
493 | WHERE
494 | p_partkey = ps_partkey
495 | AND p_brand <> 'Brand#45'
496 | AND p_type NOT LIKE 'MEDIUM POLISHED%'
497 | AND p_size IN (
498 | 49,
499 | 14,
500 | 23,
501 | 45,
502 | 19,
503 | 3,
504 | 36,
505 | 9
506 | )
507 | AND ps_suppkey NOT IN (
508 | SELECT
509 | s_suppkey
510 | FROM
511 | supplier
512 | WHERE
513 | s_comment LIKE '%Customer%Complaints%'
514 | )
515 | GROUP BY
516 | p_brand,
517 | p_type,
518 | p_size
519 | ORDER BY
520 | supplier_cnt DESC,
521 | p_brand,
522 | p_type,
523 | p_size;
524 |
525 |
526 | SELECT
527 | --Query17
528 | SUM(l_extendedprice) / 7.0 AS avg_yearly
529 | FROM
530 | lineitem,
531 | part
532 | WHERE
533 | p_partkey = l_partkey
534 | AND p_brand = 'Brand#23'
535 | AND p_container = 'MED BOX'
536 | AND l_quantity < (
537 | SELECT
538 | 0.2 * AVG(l_quantity)
539 | FROM
540 | lineitem
541 | WHERE
542 | l_partkey = p_partkey
543 | );
544 |
545 |
546 | SELECT
547 | --Query18
548 | top 100
549 | c_name,
550 | c_custkey,
551 | o_orderkey,
552 | o_orderdate,
553 | o_totalprice,
554 | SUM(l_quantity)
555 | FROM
556 | customer,
557 | orders,
558 | lineitem
559 | WHERE
560 | o_orderkey IN (
561 | SELECT
562 | l_orderkey
563 | FROM
564 | lineitem
565 | GROUP BY
566 | l_orderkey
567 | HAVING
568 | SUM(l_quantity) > 300
569 | )
570 | AND c_custkey = o_custkey
571 | AND o_orderkey = l_orderkey
572 | GROUP BY
573 | c_name,
574 | c_custkey,
575 | o_orderkey,
576 | o_orderdate,
577 | o_totalprice
578 | ORDER BY
579 | o_totalprice DESC,
580 | o_orderdate;
581 |
582 |
583 | SELECT
584 | --Query19
585 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
586 | FROM
587 | lineitem,
588 | part
589 | WHERE
590 | (
591 | p_partkey = l_partkey
592 | AND p_brand = 'Brand#12'
593 | AND p_container IN (
594 | 'SM CASE',
595 | 'SM BOX',
596 | 'SM PACK',
597 | 'SM PKG'
598 | )
599 | AND l_quantity >= 1
600 | AND l_quantity <= 1 + 10
601 | AND p_size BETWEEN 1
602 | AND 5
603 | AND l_shipmode IN ('AIR', 'AIR REG')
604 | AND l_shipinstruct = 'DELIVER IN PERSON'
605 | )
606 | OR (
607 | p_partkey = l_partkey
608 | AND p_brand = 'Brand#23'
609 | AND p_container IN (
610 | 'MED BAG',
611 | 'MED BOX',
612 | 'MED PKG',
613 | 'MED PACK'
614 | )
615 | AND l_quantity >= 10
616 | AND l_quantity <= 10 + 10
617 | AND p_size BETWEEN 1
618 | AND 10
619 | AND l_shipmode IN ('AIR', 'AIR REG')
620 | AND l_shipinstruct = 'DELIVER IN PERSON'
621 | )
622 | OR (
623 | p_partkey = l_partkey
624 | AND p_brand = 'Brand#34'
625 | AND p_container IN (
626 | 'LG CASE',
627 | 'LG BOX',
628 | 'LG PACK',
629 | 'LG PKG'
630 | )
631 | AND l_quantity >= 20
632 | AND l_quantity <= 20 + 10
633 | AND p_size BETWEEN 1
634 | AND 15
635 | AND l_shipmode IN ('AIR', 'AIR REG')
636 | AND l_shipinstruct = 'DELIVER IN PERSON'
637 | );
638 |
639 |
640 | SELECT
641 | --Query20
642 | s_name,
643 | s_address
644 | FROM
645 | supplier,
646 | nation
647 | WHERE
648 | s_suppkey IN (
649 | SELECT
650 | ps_suppkey
651 | FROM
652 | partsupp
653 | WHERE
654 | ps_partkey IN (
655 | SELECT
656 | p_partkey
657 | FROM
658 | part
659 | WHERE
660 | p_name LIKE 'forest%'
661 | )
662 | AND ps_availqty > (
663 | SELECT
664 | 0.5 * SUM(l_quantity)
665 | FROM
666 | lineitem
667 | WHERE
668 | l_partkey = ps_partkey
669 | AND l_suppkey = ps_suppkey
670 | AND l_shipdate >= CAST('1994-01-01' AS date)
671 | AND l_shipdate < CAST('1995-01-01' AS date)
672 | )
673 | )
674 | AND s_nationkey = n_nationkey
675 | AND n_name = 'CANADA'
676 | ORDER BY
677 | s_name;
678 |
679 |
680 | SELECT
681 | --Query21
682 | top 100
683 | s_name,
684 | COUNT(*) AS numwait
685 | FROM
686 | supplier,
687 | lineitem l1,
688 | orders,
689 | nation
690 | WHERE
691 | s_suppkey = l1.l_suppkey
692 | AND o_orderkey = l1.l_orderkey
693 | AND o_orderstatus = 'F'
694 | AND l1.l_receiptdate > l1.l_commitdate
695 | AND EXISTS (
696 | SELECT
697 | *
698 | FROM
699 | lineitem l2
700 | WHERE
701 | l2.l_orderkey = l1.l_orderkey
702 | AND l2.l_suppkey <> l1.l_suppkey
703 | )
704 | AND NOT EXISTS (
705 | SELECT
706 | *
707 | FROM
708 | lineitem l3
709 | WHERE
710 | l3.l_orderkey = l1.l_orderkey
711 | AND l3.l_suppkey <> l1.l_suppkey
712 | AND l3.l_receiptdate > l3.l_commitdate
713 | )
714 | AND s_nationkey = n_nationkey
715 | AND n_name = 'SAUDI ARABIA'
716 | GROUP BY
717 | s_name
718 | ORDER BY
719 | numwait DESC,
720 | s_name;
721 |
722 |
723 |
724 | SELECT
725 | --Query22
726 | cntrycode,
727 | COUNT(*) AS numcust,
728 | SUM(c_acctbal) AS totacctbal
729 | FROM
730 | (
731 | SELECT
732 | SUBSTRING(c_phone, 1, 2) AS cntrycode,
733 | c_acctbal
734 | FROM
735 | customer
736 | WHERE
737 | SUBSTRING(c_phone, 1, 2) IN (
738 | '13',
739 | '31',
740 | '23',
741 | '29',
742 | '30',
743 | '18',
744 | '17'
745 | )
746 | AND c_acctbal > (
747 | SELECT
748 | AVG(c_acctbal)
749 | FROM
750 | customer
751 | WHERE
752 | c_acctbal > 0.00
753 | AND SUBSTRING(c_phone, 1, 2) IN (
754 | '13',
755 | '31',
756 | '23',
757 | '29',
758 | '30',
759 | '18',
760 | '17'
761 | )
762 | )
763 | AND NOT EXISTS (
764 | SELECT
765 | *
766 | FROM
767 | orders
768 | WHERE
769 | o_custkey = c_custkey
770 | )
771 | ) AS custsale
772 | GROUP BY
773 | cntrycode
774 | ORDER BY
775 | cntrycode;
776 |
--------------------------------------------------------------------------------
/Database/Snowflake+SingleStore+Databricks+alloyDB.sql:
--------------------------------------------------------------------------------
1 | -- for Snowflake ALTER SESSION SET USE_CACHED_RESULT = FALSE;
2 | -- for Datbaricks SET use_cached_result = false;
3 | -- Singlestore does not have a result cache
4 |
5 |
6 | SELECT
7 | --Query01
8 | l_returnflag,
9 | l_linestatus,
10 | SUM(l_quantity) AS sum_qty,
11 | SUM(l_extendedprice) AS sum_base_price,
12 | SUM(l_extendedprice * (1 - l_discount)) AS sum_disc_price,
13 | SUM(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge,
14 | AVG(l_quantity) AS avg_qty,
15 | AVG(l_extendedprice) AS avg_price,
16 | AVG(l_discount) AS avg_disc,
17 | COUNT(*) AS count_order
18 | FROM
19 | lineitem
20 | WHERE
21 | l_shipdate <= CAST('1998-09-02' AS date)
22 | GROUP BY
23 | l_returnflag,
24 | l_linestatus
25 | ORDER BY
26 | l_returnflag,
27 | l_linestatus;
28 | SELECT
29 | --Query02
30 | s_acctbal,
31 | s_name,
32 | n_name,
33 | p_partkey,
34 | p_mfgr,
35 | s_address,
36 | s_phone,
37 | s_comment
38 | FROM
39 | part,
40 | supplier,
41 | partsupp,
42 | nation,
43 | region
44 | WHERE
45 | p_partkey = ps_partkey
46 | AND s_suppkey = ps_suppkey
47 | AND p_size = 15
48 | AND p_type LIKE '%BRASS'
49 | AND s_nationkey = n_nationkey
50 | AND n_regionkey = r_regionkey
51 | AND r_name = 'EUROPE'
52 | AND ps_supplycost = (
53 | SELECT
54 | MIN(ps_supplycost)
55 | FROM
56 | partsupp,
57 | supplier,
58 | nation,
59 | region
60 | WHERE
61 | p_partkey = ps_partkey
62 | AND s_suppkey = ps_suppkey
63 | AND s_nationkey = n_nationkey
64 | AND n_regionkey = r_regionkey
65 | AND r_name = 'EUROPE'
66 | )
67 | ORDER BY
68 | s_acctbal DESC,
69 | n_name,
70 | s_name,
71 | p_partkey
72 | LIMIT
73 | 100;
74 | SELECT
75 | --Query03
76 | l_orderkey,
77 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
78 | o_orderdate,
79 | o_shippriority
80 | FROM
81 | customer,
82 | orders,
83 | lineitem
84 | WHERE
85 | c_mktsegment = 'BUILDING'
86 | AND c_custkey = o_custkey
87 | AND l_orderkey = o_orderkey
88 | AND o_orderdate < CAST('1995-03-15' AS date)
89 | AND l_shipdate > CAST('1995-03-15' AS date)
90 | GROUP BY
91 | l_orderkey,
92 | o_orderdate,
93 | o_shippriority
94 | ORDER BY
95 | revenue DESC,
96 | o_orderdate
97 | LIMIT
98 | 10;
99 | SELECT
100 | --Query04
101 | o_orderpriority,
102 | COUNT(*) AS order_count
103 | FROM
104 | orders
105 | WHERE
106 | o_orderdate >= CAST('1993-07-01' AS date)
107 | AND o_orderdate < CAST('1993-10-01' AS date)
108 | AND EXISTS (
109 | SELECT
110 | *
111 | FROM
112 | lineitem
113 | WHERE
114 | l_orderkey = o_orderkey
115 | AND l_commitdate < l_receiptdate
116 | )
117 | GROUP BY
118 | o_orderpriority
119 | ORDER BY
120 | o_orderpriority;
121 | SELECT
122 | --Query05
123 | n_name,
124 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
125 | FROM
126 | customer,
127 | orders,
128 | lineitem,
129 | supplier,
130 | nation,
131 | region
132 | WHERE
133 | c_custkey = o_custkey
134 | AND l_orderkey = o_orderkey
135 | AND l_suppkey = s_suppkey
136 | AND c_nationkey = s_nationkey
137 | AND s_nationkey = n_nationkey
138 | AND n_regionkey = r_regionkey
139 | AND r_name = 'ASIA'
140 | AND o_orderdate >= CAST('1994-01-01' AS date)
141 | AND o_orderdate < CAST('1995-01-01' AS date)
142 | GROUP BY
143 | n_name
144 | ORDER BY
145 | revenue DESC;
146 | SELECT
147 | --Query06
148 | SUM(l_extendedprice * l_discount) AS revenue
149 | FROM
150 | lineitem
151 | WHERE
152 | l_shipdate >= CAST('1994-01-01' AS date)
153 | AND l_shipdate < CAST('1995-01-01' AS date)
154 | AND l_discount BETWEEN 0.05
155 | AND 0.07
156 | AND l_quantity < 24;
157 | SELECT
158 | --Query07
159 | supp_nation,
160 | cust_nation,
161 | l_year,
162 | SUM(volume) AS revenue
163 | FROM
164 | (
165 | SELECT
166 | n1.n_name AS supp_nation,
167 | n2.n_name AS cust_nation,
168 | EXTRACT(
169 | year
170 | FROM
171 | l_shipdate
172 | ) AS l_year,
173 | l_extendedprice * (1 - l_discount) AS volume
174 | FROM
175 | supplier,
176 | lineitem,
177 | orders,
178 | customer,
179 | nation n1,
180 | nation n2
181 | WHERE
182 | s_suppkey = l_suppkey
183 | AND o_orderkey = l_orderkey
184 | AND c_custkey = o_custkey
185 | AND s_nationkey = n1.n_nationkey
186 | AND c_nationkey = n2.n_nationkey
187 | AND (
188 | (
189 | n1.n_name = 'FRANCE'
190 | AND n2.n_name = 'GERMANY'
191 | )
192 | OR (
193 | n1.n_name = 'GERMANY'
194 | AND n2.n_name = 'FRANCE'
195 | )
196 | )
197 | AND l_shipdate BETWEEN CAST('1995-01-01' AS date)
198 | AND CAST('1996-12-31' AS date)
199 | ) AS shipping
200 | GROUP BY
201 | supp_nation,
202 | cust_nation,
203 | l_year
204 | ORDER BY
205 | supp_nation,
206 | cust_nation,
207 | l_year;
208 | SELECT
209 | --Query08
210 | o_year,
211 | SUM(
212 | CASE
213 | WHEN nation = 'BRAZIL' THEN volume
214 | ELSE 0
215 | END
216 | ) / SUM(volume) AS mkt_share
217 | FROM
218 | (
219 | SELECT
220 | EXTRACT(
221 | year
222 | FROM
223 | o_orderdate
224 | ) AS o_year,
225 | l_extendedprice * (1 - l_discount) AS volume,
226 | n2.n_name AS nation
227 | FROM
228 | part,
229 | supplier,
230 | lineitem,
231 | orders,
232 | customer,
233 | nation n1,
234 | nation n2,
235 | region
236 | WHERE
237 | p_partkey = l_partkey
238 | AND s_suppkey = l_suppkey
239 | AND l_orderkey = o_orderkey
240 | AND o_custkey = c_custkey
241 | AND c_nationkey = n1.n_nationkey
242 | AND n1.n_regionkey = r_regionkey
243 | AND r_name = 'AMERICA'
244 | AND s_nationkey = n2.n_nationkey
245 | AND o_orderdate BETWEEN CAST('1995-01-01' AS date)
246 | AND CAST('1996-12-31' AS date)
247 | AND p_type = 'ECONOMY ANODIZED STEEL'
248 | ) AS all_nations
249 | GROUP BY
250 | o_year
251 | ORDER BY
252 | o_year;
253 | SELECT
254 | --Query09
255 | nation,
256 | o_year,
257 | SUM(amount) AS sum_profit
258 | FROM
259 | (
260 | SELECT
261 | n_name AS nation,
262 | EXTRACT(
263 | year
264 | FROM
265 | o_orderdate
266 | ) AS o_year,
267 | l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity AS amount
268 | FROM
269 | part,
270 | supplier,
271 | lineitem,
272 | partsupp,
273 | orders,
274 | nation
275 | WHERE
276 | s_suppkey = l_suppkey
277 | AND ps_suppkey = l_suppkey
278 | AND ps_partkey = l_partkey
279 | AND p_partkey = l_partkey
280 | AND o_orderkey = l_orderkey
281 | AND s_nationkey = n_nationkey
282 | AND p_name LIKE '%green%'
283 | ) AS profit
284 | GROUP BY
285 | nation,
286 | o_year
287 | ORDER BY
288 | nation,
289 | o_year DESC;
290 | SELECT
291 | --Query10
292 | c_custkey,
293 | c_name,
294 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
295 | c_acctbal,
296 | n_name,
297 | c_address,
298 | c_phone,
299 | c_comment
300 | FROM
301 | customer,
302 | orders,
303 | lineitem,
304 | nation
305 | WHERE
306 | c_custkey = o_custkey
307 | AND l_orderkey = o_orderkey
308 | AND o_orderdate >= CAST('1993-10-01' AS date)
309 | AND o_orderdate < CAST('1994-01-01' AS date)
310 | AND l_returnflag = 'R'
311 | AND c_nationkey = n_nationkey
312 | GROUP BY
313 | c_custkey,
314 | c_name,
315 | c_acctbal,
316 | c_phone,
317 | n_name,
318 | c_address,
319 | c_comment
320 | ORDER BY
321 | revenue DESC
322 | LIMIT
323 | 20;
324 | SELECT
325 | --Query11
326 | ps_partkey,
327 | SUM(ps_supplycost * ps_availqty) AS value
328 | FROM
329 | partsupp,
330 | supplier,
331 | nation
332 | WHERE
333 | ps_suppkey = s_suppkey
334 | AND s_nationkey = n_nationkey
335 | AND n_name = 'GERMANY'
336 | GROUP BY
337 | ps_partkey
338 | HAVING
339 | SUM(ps_supplycost * ps_availqty) > (
340 | SELECT
341 | SUM(ps_supplycost * ps_availqty) * (0.0001/10)
342 | -- SUM(ps_supplycost * ps_availqty) * 1
343 | FROM
344 | partsupp,
345 | supplier,
346 | nation
347 | WHERE
348 | ps_suppkey = s_suppkey
349 | AND s_nationkey = n_nationkey
350 | AND n_name = 'GERMANY'
351 | )
352 | ORDER BY
353 | value DESC;
354 |
355 |
356 |
357 | SELECT
358 | --Query12
359 | l_shipmode,
360 | SUM(
361 | CASE
362 | WHEN o_orderpriority = '1-URGENT'
363 | OR o_orderpriority = '2-HIGH' THEN 1
364 | ELSE 0
365 | END
366 | ) AS high_line_count,
367 | SUM(
368 | CASE
369 | WHEN o_orderpriority <> '1-URGENT'
370 | AND o_orderpriority <> '2-HIGH' THEN 1
371 | ELSE 0
372 | END
373 | ) AS low_line_count
374 | FROM
375 | orders,
376 | lineitem
377 | WHERE
378 | o_orderkey = l_orderkey
379 | AND l_shipmode IN ('MAIL', 'SHIP')
380 | AND l_commitdate < l_receiptdate
381 | AND l_shipdate < l_commitdate
382 | AND l_receiptdate >= CAST('1994-01-01' AS date)
383 | AND l_receiptdate < CAST('1995-01-01' AS date)
384 | GROUP BY
385 | l_shipmode
386 | ORDER BY
387 | l_shipmode;
388 | SELECT
389 | --Query13
390 | c_count,
391 | COUNT(*) AS custdist
392 | FROM
393 | (
394 | SELECT
395 | c_custkey,
396 | COUNT(o_orderkey) AS c_count
397 | FROM
398 | customer
399 | LEFT OUTER JOIN orders ON c_custkey = o_custkey
400 | AND o_comment NOT LIKE '%special%requests%'
401 | GROUP BY
402 | c_custkey
403 | ) AS c_orders
404 | GROUP BY
405 | c_count
406 | ORDER BY
407 | custdist DESC,
408 | c_count DESC;
409 | SELECT
410 | --Query14
411 | 100.00 * SUM(
412 | CASE
413 | WHEN p_type LIKE 'PROMO%' THEN l_extendedprice * (1 - l_discount)
414 | ELSE 0
415 | END
416 | ) / SUM(l_extendedprice * (1 - l_discount)) AS promo_revenue
417 | FROM
418 | lineitem,
419 | part
420 | WHERE
421 | l_partkey = p_partkey
422 | AND l_shipdate >= date '1995-09-01'
423 | AND l_shipdate < CAST('1995-10-01' AS date);
424 | SELECT
425 | --Query15
426 | s_suppkey,
427 | s_name,
428 | s_address,
429 | s_phone,
430 | total_revenue
431 | FROM
432 | supplier,
433 | (
434 | SELECT
435 | l_suppkey AS supplier_no,
436 | SUM(l_extendedprice * (1 - l_discount)) AS total_revenue
437 | FROM
438 | lineitem
439 | WHERE
440 | l_shipdate >= CAST('1996-01-01' AS date)
441 | AND l_shipdate < CAST('1996-04-01' AS date)
442 | GROUP BY
443 | supplier_no
444 | ) revenue0
445 | WHERE
446 | s_suppkey = supplier_no
447 | AND total_revenue = (
448 | SELECT
449 | MAX(total_revenue)
450 | FROM
451 | (
452 | SELECT
453 | l_suppkey AS supplier_no,
454 | SUM(l_extendedprice * (1 - l_discount)) AS total_revenue
455 | FROM
456 | lineitem
457 | WHERE
458 | l_shipdate >= CAST('1996-01-01' AS date)
459 | AND l_shipdate < CAST('1996-04-01' AS date)
460 | GROUP BY
461 | supplier_no
462 | ) revenue1
463 | )
464 | ORDER BY
465 | s_suppkey;
466 | SELECT
467 | --Query16
468 | p_brand,
469 | p_type,
470 | p_size,
471 | COUNT(DISTINCT ps_suppkey) AS supplier_cnt
472 | FROM
473 | partsupp,
474 | part
475 | WHERE
476 | p_partkey = ps_partkey
477 | AND p_brand <> 'Brand#45'
478 | AND p_type NOT LIKE 'MEDIUM POLISHED%'
479 | AND p_size IN (
480 | 49,
481 | 14,
482 | 23,
483 | 45,
484 | 19,
485 | 3,
486 | 36,
487 | 9
488 | )
489 | AND ps_suppkey NOT IN (
490 | SELECT
491 | s_suppkey
492 | FROM
493 | supplier
494 | WHERE
495 | s_comment LIKE '%Customer%Complaints%'
496 | )
497 | GROUP BY
498 | p_brand,
499 | p_type,
500 | p_size
501 | ORDER BY
502 | supplier_cnt DESC,
503 | p_brand,
504 | p_type,
505 | p_size;
506 | SELECT
507 | --Query17
508 | SUM(l_extendedprice) / 7.0 AS avg_yearly
509 | FROM
510 | lineitem,
511 | part
512 | WHERE
513 | p_partkey = l_partkey
514 | AND p_brand = 'Brand#23'
515 | AND p_container = 'MED BOX'
516 | AND l_quantity < (
517 | SELECT
518 | 0.2 * AVG(l_quantity)
519 | FROM
520 | lineitem
521 | WHERE
522 | l_partkey = p_partkey
523 | );
524 | SELECT
525 | --Query18
526 | c_name,
527 | c_custkey,
528 | o_orderkey,
529 | o_orderdate,
530 | o_totalprice,
531 | SUM(l_quantity)
532 | FROM
533 | customer,
534 | orders,
535 | lineitem
536 | WHERE
537 | o_orderkey IN (
538 | SELECT
539 | l_orderkey
540 | FROM
541 | lineitem
542 | GROUP BY
543 | l_orderkey
544 | HAVING
545 | SUM(l_quantity) > 300
546 | )
547 | AND c_custkey = o_custkey
548 | AND o_orderkey = l_orderkey
549 | GROUP BY
550 | c_name,
551 | c_custkey,
552 | o_orderkey,
553 | o_orderdate,
554 | o_totalprice
555 | ORDER BY
556 | o_totalprice DESC,
557 | o_orderdate
558 | LIMIT
559 | 100;
560 | SELECT
561 | --Query19
562 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
563 | FROM
564 | lineitem,
565 | part
566 | WHERE
567 | (
568 | p_partkey = l_partkey
569 | AND p_brand = 'Brand#12'
570 | AND p_container IN (
571 | 'SM CASE',
572 | 'SM BOX',
573 | 'SM PACK',
574 | 'SM PKG'
575 | )
576 | AND l_quantity >= 1
577 | AND l_quantity <= 1 + 10
578 | AND p_size BETWEEN 1
579 | AND 5
580 | AND l_shipmode IN ('AIR', 'AIR REG')
581 | AND l_shipinstruct = 'DELIVER IN PERSON'
582 | )
583 | OR (
584 | p_partkey = l_partkey
585 | AND p_brand = 'Brand#23'
586 | AND p_container IN (
587 | 'MED BAG',
588 | 'MED BOX',
589 | 'MED PKG',
590 | 'MED PACK'
591 | )
592 | AND l_quantity >= 10
593 | AND l_quantity <= 10 + 10
594 | AND p_size BETWEEN 1
595 | AND 10
596 | AND l_shipmode IN ('AIR', 'AIR REG')
597 | AND l_shipinstruct = 'DELIVER IN PERSON'
598 | )
599 | OR (
600 | p_partkey = l_partkey
601 | AND p_brand = 'Brand#34'
602 | AND p_container IN (
603 | 'LG CASE',
604 | 'LG BOX',
605 | 'LG PACK',
606 | 'LG PKG'
607 | )
608 | AND l_quantity >= 20
609 | AND l_quantity <= 20 + 10
610 | AND p_size BETWEEN 1
611 | AND 15
612 | AND l_shipmode IN ('AIR', 'AIR REG')
613 | AND l_shipinstruct = 'DELIVER IN PERSON'
614 | );
615 | SELECT
616 | --Query20
617 | s_name,
618 | s_address
619 | FROM
620 | supplier,
621 | nation
622 | WHERE
623 | s_suppkey IN (
624 | SELECT
625 | ps_suppkey
626 | FROM
627 | partsupp
628 | WHERE
629 | ps_partkey IN (
630 | SELECT
631 | p_partkey
632 | FROM
633 | part
634 | WHERE
635 | p_name LIKE 'forest%'
636 | )
637 | AND ps_availqty > (
638 | SELECT
639 | 0.5 * SUM(l_quantity)
640 | FROM
641 | lineitem
642 | WHERE
643 | l_partkey = ps_partkey
644 | AND l_suppkey = ps_suppkey
645 | AND l_shipdate >= CAST('1994-01-01' AS date)
646 | AND l_shipdate < CAST('1995-01-01' AS date)
647 | )
648 | )
649 | AND s_nationkey = n_nationkey
650 | AND n_name = 'CANADA'
651 | ORDER BY
652 | s_name;
653 | SELECT
654 | --Query21
655 | s_name,
656 | COUNT(*) AS numwait
657 | FROM
658 | supplier,
659 | lineitem l1,
660 | orders,
661 | nation
662 | WHERE
663 | s_suppkey = l1.l_suppkey
664 | AND o_orderkey = l1.l_orderkey
665 | AND o_orderstatus = 'F'
666 | AND l1.l_receiptdate > l1.l_commitdate
667 | AND EXISTS (
668 | SELECT
669 | *
670 | FROM
671 | lineitem l2
672 | WHERE
673 | l2.l_orderkey = l1.l_orderkey
674 | AND l2.l_suppkey <> l1.l_suppkey
675 | )
676 | AND NOT EXISTS (
677 | SELECT
678 | *
679 | FROM
680 | lineitem l3
681 | WHERE
682 | l3.l_orderkey = l1.l_orderkey
683 | AND l3.l_suppkey <> l1.l_suppkey
684 | AND l3.l_receiptdate > l3.l_commitdate
685 | )
686 | AND s_nationkey = n_nationkey
687 | AND n_name = 'SAUDI ARABIA'
688 | GROUP BY
689 | s_name
690 | ORDER BY
691 | numwait DESC,
692 | s_name
693 | LIMIT
694 | 100;
695 | SELECT
696 | --Query22
697 | cntrycode,
698 | COUNT(*) AS numcust,
699 | SUM(c_acctbal) AS totacctbal
700 | FROM
701 | (
702 | SELECT
703 | SUBSTRING(c_phone, 1, 2) AS cntrycode,
704 | c_acctbal
705 | FROM
706 | customer
707 | WHERE
708 | SUBSTRING(c_phone, 1, 2) IN (
709 | '13',
710 | '31',
711 | '23',
712 | '29',
713 | '30',
714 | '18',
715 | '17'
716 | )
717 | AND c_acctbal > (
718 | SELECT
719 | AVG(c_acctbal)
720 | FROM
721 | customer
722 | WHERE
723 | c_acctbal > 0.00
724 | AND SUBSTRING(c_phone, 1, 2) IN (
725 | '13',
726 | '31',
727 | '23',
728 | '29',
729 | '30',
730 | '18',
731 | '17'
732 | )
733 | )
734 | AND NOT EXISTS (
735 | SELECT
736 | *
737 | FROM
738 | orders
739 | WHERE
740 | o_custkey = c_custkey
741 | )
742 | ) AS custsale
743 | GROUP BY
744 | cntrycode
745 | ORDER BY
746 | cntrycode;
747 |
--------------------------------------------------------------------------------
/Database/DuckDB/duckdb.py:
--------------------------------------------------------------------------------
1 | import duckdb
2 | con = duckdb.connect(database=':memory:')
3 |
4 |
5 |
6 | df =con.execute('''
7 | PRAGMA enable_profiling='json';
8 | PRAGMA profile_output='./json/1.json';
9 |
10 |
11 |
12 | CREATE VIEW partsupp AS SELECT * FROM 'partsupp.parquet';
13 | CREATE VIEW part AS SELECT * FROM 'part.parquet';
14 | CREATE VIEW supplier AS SELECT * FROM 'supplier.parquet';
15 | CREATE VIEW nation AS SELECT * FROM 'nation.parquet';
16 | CREATE VIEW region AS SELECT * FROM 'region.parquet';
17 | CREATE VIEW lineitem AS SELECT * FROM 'lineitem.parquet';
18 | CREATE VIEW orders AS SELECT * FROM 'orders.parquet';
19 | CREATE VIEW customer AS SELECT * FROM 'customer.parquet';
20 |
21 | SELECT
22 | --Query01
23 | l_returnflag,
24 | l_linestatus,
25 | SUM(l_quantity) AS sum_qty,
26 | SUM(l_extendedprice) AS sum_base_price,
27 | SUM(l_extendedprice * (1 - l_discount)) AS sum_disc_price,
28 | SUM(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge,
29 | AVG(l_quantity) AS avg_qty,
30 | AVG(l_extendedprice) AS avg_price,
31 | AVG(l_discount) AS avg_disc,
32 | COUNT(*) AS count_order
33 | FROM
34 | lineitem
35 | WHERE
36 | l_shipdate <= CAST('1998-09-02' AS date)
37 | GROUP BY
38 | l_returnflag,
39 | l_linestatus
40 | ORDER BY
41 | l_returnflag,
42 | l_linestatus;
43 |
44 |
45 |
46 | ''').fetchdf()
47 | print(df)
48 |
49 |
50 |
51 | df =con.execute('''
52 | PRAGMA enable_profiling='json';
53 | PRAGMA profile_output='./json/2.json';
54 |
55 |
56 | SELECT
57 | --Query02
58 | s_acctbal,
59 | s_name,
60 | n_name,
61 | p_partkey,
62 | p_mfgr,
63 | s_address,
64 | s_phone,
65 | s_comment
66 | FROM
67 | part,
68 | supplier,
69 | partsupp,
70 | nation,
71 | region
72 | WHERE
73 | p_partkey = ps_partkey
74 | AND s_suppkey = ps_suppkey
75 | AND p_size = 15
76 | AND p_type LIKE '%BRASS'
77 | AND s_nationkey = n_nationkey
78 | AND n_regionkey = r_regionkey
79 | AND r_name = 'EUROPE'
80 | AND ps_supplycost = (
81 | SELECT
82 | MIN(ps_supplycost)
83 | FROM
84 | partsupp,
85 | supplier,
86 | nation,
87 | region
88 | WHERE
89 | p_partkey = ps_partkey
90 | AND s_suppkey = ps_suppkey
91 | AND s_nationkey = n_nationkey
92 | AND n_regionkey = r_regionkey
93 | AND r_name = 'EUROPE'
94 | )
95 | ORDER BY
96 | s_acctbal DESC,
97 | n_name,
98 | s_name,
99 | p_partkey
100 | LIMIT
101 | 100;
102 |
103 |
104 |
105 | ''').fetchdf()
106 | print(df)
107 |
108 |
109 | df =con.execute('''
110 | PRAGMA enable_profiling='json';
111 | PRAGMA profile_output='./json/3.json';
112 |
113 |
114 | SELECT
115 | --Query03
116 | l_orderkey,
117 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
118 | o_orderdate,
119 | o_shippriority
120 | FROM
121 | customer,
122 | orders,
123 | lineitem
124 | WHERE
125 | c_mktsegment = 'BUILDING'
126 | AND c_custkey = o_custkey
127 | AND l_orderkey = o_orderkey
128 | AND o_orderdate < CAST('1995-03-15' AS date)
129 | AND l_shipdate > CAST('1995-03-15' AS date)
130 | GROUP BY
131 | l_orderkey,
132 | o_orderdate,
133 | o_shippriority
134 | ORDER BY
135 | revenue DESC,
136 | o_orderdate
137 | LIMIT
138 | 10;
139 |
140 |
141 |
142 | ''').fetchdf()
143 | print(df)
144 |
145 | df =con.execute('''
146 | PRAGMA enable_profiling='json';
147 | PRAGMA profile_output='./json/4.json';
148 |
149 |
150 | SELECT
151 | --Query04
152 | o_orderpriority,
153 | COUNT(*) AS order_count
154 | FROM
155 | orders
156 | WHERE
157 | o_orderdate >= CAST('1993-07-01' AS date)
158 | AND o_orderdate < CAST('1993-10-01' AS date)
159 | AND EXISTS (
160 | SELECT
161 | *
162 | FROM
163 | lineitem
164 | WHERE
165 | l_orderkey = o_orderkey
166 | AND l_commitdate < l_receiptdate
167 | )
168 | GROUP BY
169 | o_orderpriority
170 | ORDER BY
171 | o_orderpriority;
172 |
173 |
174 |
175 | ''').fetchdf()
176 | print(df)
177 |
178 | df =con.execute('''
179 | PRAGMA enable_profiling='json';
180 | PRAGMA profile_output='./json/5.json';
181 |
182 |
183 | SELECT
184 | --Query05
185 | n_name,
186 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
187 | FROM
188 | customer,
189 | orders,
190 | lineitem,
191 | supplier,
192 | nation,
193 | region
194 | WHERE
195 | c_custkey = o_custkey
196 | AND l_orderkey = o_orderkey
197 | AND l_suppkey = s_suppkey
198 | AND c_nationkey = s_nationkey
199 | AND s_nationkey = n_nationkey
200 | AND n_regionkey = r_regionkey
201 | AND r_name = 'ASIA'
202 | AND o_orderdate >= CAST('1994-01-01' AS date)
203 | AND o_orderdate < CAST('1995-01-01' AS date)
204 | GROUP BY
205 | n_name
206 | ORDER BY
207 | revenue DESC;
208 |
209 |
210 |
211 | ''').fetchdf()
212 | print(df)
213 |
214 | df =con.execute('''
215 | PRAGMA enable_profiling='json';
216 | PRAGMA profile_output='./json/6.json';
217 |
218 |
219 | SELECT
220 | --Query06
221 | SUM(l_extendedprice * l_discount) AS revenue
222 | FROM
223 | lineitem
224 | WHERE
225 | l_shipdate >= CAST('1994-01-01' AS date)
226 | AND l_shipdate < CAST('1995-01-01' AS date)
227 | AND l_discount BETWEEN 0.05
228 | AND 0.07
229 | AND l_quantity < 24;
230 |
231 |
232 |
233 | ''').fetchdf()
234 | print(df)
235 |
236 | df =con.execute('''
237 | PRAGMA enable_profiling='json';
238 | PRAGMA profile_output='./json/7.json';
239 |
240 |
241 | SELECT
242 | --Query07
243 | supp_nation,
244 | cust_nation,
245 | l_year,
246 | SUM(volume) AS revenue
247 | FROM
248 | (
249 | SELECT
250 | n1.n_name AS supp_nation,
251 | n2.n_name AS cust_nation,
252 | EXTRACT(
253 | year
254 | FROM
255 | l_shipdate
256 | ) AS l_year,
257 | l_extendedprice * (1 - l_discount) AS volume
258 | FROM
259 | supplier,
260 | lineitem,
261 | orders,
262 | customer,
263 | nation n1,
264 | nation n2
265 | WHERE
266 | s_suppkey = l_suppkey
267 | AND o_orderkey = l_orderkey
268 | AND c_custkey = o_custkey
269 | AND s_nationkey = n1.n_nationkey
270 | AND c_nationkey = n2.n_nationkey
271 | AND (
272 | (
273 | n1.n_name = 'FRANCE'
274 | AND n2.n_name = 'GERMANY'
275 | )
276 | OR (
277 | n1.n_name = 'GERMANY'
278 | AND n2.n_name = 'FRANCE'
279 | )
280 | )
281 | AND l_shipdate BETWEEN CAST('1995-01-01' AS date)
282 | AND CAST('1996-12-31' AS date)
283 | ) AS shipping
284 | GROUP BY
285 | supp_nation,
286 | cust_nation,
287 | l_year
288 | ORDER BY
289 | supp_nation,
290 | cust_nation,
291 | l_year;
292 |
293 |
294 |
295 | ''').fetchdf()
296 | print(df)
297 |
298 | df =con.execute('''
299 | PRAGMA enable_profiling='json';
300 | PRAGMA profile_output='./json/8.json';
301 |
302 |
303 | SELECT
304 | --Query08
305 | o_year,
306 | SUM(
307 | CASE
308 | WHEN nation = 'BRAZIL' THEN volume
309 | ELSE 0
310 | END
311 | ) / SUM(volume) AS mkt_share
312 | FROM
313 | (
314 | SELECT
315 | EXTRACT(
316 | year
317 | FROM
318 | o_orderdate
319 | ) AS o_year,
320 | l_extendedprice * (1 - l_discount) AS volume,
321 | n2.n_name AS nation
322 | FROM
323 | part,
324 | supplier,
325 | lineitem,
326 | orders,
327 | customer,
328 | nation n1,
329 | nation n2,
330 | region
331 | WHERE
332 | p_partkey = l_partkey
333 | AND s_suppkey = l_suppkey
334 | AND l_orderkey = o_orderkey
335 | AND o_custkey = c_custkey
336 | AND c_nationkey = n1.n_nationkey
337 | AND n1.n_regionkey = r_regionkey
338 | AND r_name = 'AMERICA'
339 | AND s_nationkey = n2.n_nationkey
340 | AND o_orderdate BETWEEN CAST('1995-01-01' AS date)
341 | AND CAST('1996-12-31' AS date)
342 | AND p_type = 'ECONOMY ANODIZED STEEL'
343 | ) AS all_nations
344 | GROUP BY
345 | o_year
346 | ORDER BY
347 | o_year;
348 |
349 |
350 |
351 | ''').fetchdf()
352 | print(df)
353 |
354 | df =con.execute('''
355 | PRAGMA enable_profiling='json';
356 | PRAGMA profile_output='./json/9.json';
357 |
358 |
359 |
360 |
361 | SELECT
362 | --Query09
363 | nation,
364 | o_year,
365 | SUM(amount) AS sum_profit
366 | FROM
367 | (
368 | SELECT
369 | n_name AS nation,
370 | EXTRACT(
371 | year
372 | FROM
373 | o_orderdate
374 | ) AS o_year,
375 | l_extendedprice * (1 - l_discount) - ps_supplycost * l_quantity AS amount
376 | FROM
377 | part,
378 | supplier,
379 | lineitem,
380 | partsupp,
381 | orders,
382 | nation
383 | WHERE
384 | s_suppkey = l_suppkey
385 | AND ps_suppkey = l_suppkey
386 | AND ps_partkey = l_partkey
387 | AND p_partkey = l_partkey
388 | AND o_orderkey = l_orderkey
389 | AND s_nationkey = n_nationkey
390 | AND p_name LIKE '%green%'
391 | ) AS profit
392 | GROUP BY
393 | nation,
394 | o_year
395 | ORDER BY
396 | nation,
397 | o_year DESC;
398 |
399 |
400 |
401 | ''').fetchdf()
402 | print(df)
403 |
404 | df =con.execute('''
405 | PRAGMA enable_profiling='json';
406 | PRAGMA profile_output='./json/10.json';
407 |
408 |
409 | SELECT
410 | --Query10
411 | c_custkey,
412 | c_name,
413 | SUM(l_extendedprice * (1 - l_discount)) AS revenue,
414 | c_acctbal,
415 | n_name,
416 | c_address,
417 | c_phone,
418 | c_comment
419 | FROM
420 | customer,
421 | orders,
422 | lineitem,
423 | nation
424 | WHERE
425 | c_custkey = o_custkey
426 | AND l_orderkey = o_orderkey
427 | AND o_orderdate >= CAST('1993-10-01' AS date)
428 | AND o_orderdate < CAST('1994-01-01' AS date)
429 | AND l_returnflag = 'R'
430 | AND c_nationkey = n_nationkey
431 | GROUP BY
432 | c_custkey,
433 | c_name,
434 | c_acctbal,
435 | c_phone,
436 | n_name,
437 | c_address,
438 | c_comment
439 | ORDER BY
440 | revenue DESC
441 | LIMIT
442 | 20;
443 |
444 |
445 |
446 | ''').fetchdf()
447 | print(df)
448 |
449 |
450 | df =con.execute('''
451 | PRAGMA enable_profiling='json';
452 | PRAGMA profile_output='./json/11.json';
453 |
454 |
455 | SELECT
456 | --Query11
457 | ps_partkey,
458 | SUM(ps_supplycost * ps_availqty) AS value
459 | FROM
460 | partsupp,
461 | supplier,
462 | nation
463 | WHERE
464 | ps_suppkey = s_suppkey
465 | AND s_nationkey = n_nationkey
466 | AND n_name = 'GERMANY'
467 | GROUP BY
468 | ps_partkey
469 | HAVING
470 | SUM(ps_supplycost * ps_availqty) > (
471 | SELECT
472 | SUM(ps_supplycost * ps_availqty) * (0.0001/10)
473 | -- SUM(ps_supplycost * ps_availqty) * 1
474 | FROM
475 | partsupp,
476 | supplier,
477 | nation
478 | WHERE
479 | ps_suppkey = s_suppkey
480 | AND s_nationkey = n_nationkey
481 | AND n_name = 'GERMANY'
482 | )
483 | ORDER BY
484 | value DESC;
485 |
486 |
487 |
488 | ''').fetchdf()
489 | print(df)
490 |
491 | df =con.execute('''
492 | PRAGMA enable_profiling='json';
493 | PRAGMA profile_output='./json/12.json';
494 |
495 |
496 | SELECT
497 | --Query12
498 | l_shipmode,
499 | SUM(
500 | CASE
501 | WHEN o_orderpriority = '1-URGENT'
502 | OR o_orderpriority = '2-HIGH' THEN 1
503 | ELSE 0
504 | END
505 | ) AS high_line_count,
506 | SUM(
507 | CASE
508 | WHEN o_orderpriority <> '1-URGENT'
509 | AND o_orderpriority <> '2-HIGH' THEN 1
510 | ELSE 0
511 | END
512 | ) AS low_line_count
513 | FROM
514 | orders,
515 | lineitem
516 | WHERE
517 | o_orderkey = l_orderkey
518 | AND l_shipmode IN ('MAIL', 'SHIP')
519 | AND l_commitdate < l_receiptdate
520 | AND l_shipdate < l_commitdate
521 | AND l_receiptdate >= CAST('1994-01-01' AS date)
522 | AND l_receiptdate < CAST('1995-01-01' AS date)
523 | GROUP BY
524 | l_shipmode
525 | ORDER BY
526 | l_shipmode;
527 |
528 |
529 |
530 | ''').fetchdf()
531 | print(df)
532 |
533 | df =con.execute('''
534 | PRAGMA enable_profiling='json';
535 | PRAGMA profile_output='./json/13.json';
536 |
537 |
538 | SELECT
539 | --Query13
540 | c_count,
541 | COUNT(*) AS custdist
542 | FROM
543 | (
544 | SELECT
545 | c_custkey,
546 | COUNT(o_orderkey) AS c_count
547 | FROM
548 | customer
549 | LEFT OUTER JOIN orders ON c_custkey = o_custkey
550 | AND o_comment NOT LIKE '%special%requests%'
551 | GROUP BY
552 | c_custkey
553 | ) AS c_orders
554 | GROUP BY
555 | c_count
556 | ORDER BY
557 | custdist DESC,
558 | c_count DESC;
559 |
560 |
561 |
562 | ''').fetchdf()
563 | print(df)
564 |
565 |
566 | df =con.execute('''
567 | PRAGMA enable_profiling='json';
568 | PRAGMA profile_output='./json/14.json';
569 |
570 |
571 | SELECT
572 | --Query14
573 | 100.00 * SUM(
574 | CASE
575 | WHEN p_type LIKE 'PROMO%' THEN l_extendedprice * (1 - l_discount)
576 | ELSE 0
577 | END
578 | ) / SUM(l_extendedprice * (1 - l_discount)) AS promo_revenue
579 | FROM
580 | lineitem,
581 | part
582 | WHERE
583 | l_partkey = p_partkey
584 | AND l_shipdate >= date '1995-09-01'
585 | AND l_shipdate < CAST('1995-10-01' AS date);
586 |
587 |
588 |
589 | ''').fetchdf()
590 | print(df)
591 |
592 |
593 | df =con.execute('''
594 | PRAGMA enable_profiling='json';
595 | PRAGMA profile_output='./json/15.json';
596 |
597 |
598 | SELECT
599 | --Query15
600 | s_suppkey,
601 | s_name,
602 | s_address,
603 | s_phone,
604 | total_revenue
605 | FROM
606 | supplier,
607 | (
608 | SELECT
609 | l_suppkey AS supplier_no,
610 | SUM(l_extendedprice * (1 - l_discount)) AS total_revenue
611 | FROM
612 | lineitem
613 | WHERE
614 | l_shipdate >= CAST('1996-01-01' AS date)
615 | AND l_shipdate < CAST('1996-04-01' AS date)
616 | GROUP BY
617 | supplier_no
618 | ) revenue0
619 | WHERE
620 | s_suppkey = supplier_no
621 | AND total_revenue = (
622 | SELECT
623 | MAX(total_revenue)
624 | FROM
625 | (
626 | SELECT
627 | l_suppkey AS supplier_no,
628 | SUM(l_extendedprice * (1 - l_discount)) AS total_revenue
629 | FROM
630 | lineitem
631 | WHERE
632 | l_shipdate >= CAST('1996-01-01' AS date)
633 | AND l_shipdate < CAST('1996-04-01' AS date)
634 | GROUP BY
635 | supplier_no
636 | ) revenue1
637 | )
638 | ORDER BY
639 | s_suppkey;
640 |
641 |
642 |
643 | ''').fetchdf()
644 | print(df)
645 |
646 |
647 | df =con.execute('''
648 | PRAGMA enable_profiling='json';
649 | PRAGMA profile_output='./json/16.json';
650 |
651 |
652 | SELECT
653 | --Query16
654 | p_brand,
655 | p_type,
656 | p_size,
657 | COUNT(DISTINCT ps_suppkey) AS supplier_cnt
658 | FROM
659 | partsupp,
660 | part
661 | WHERE
662 | p_partkey = ps_partkey
663 | AND p_brand <> 'Brand#45'
664 | AND p_type NOT LIKE 'MEDIUM POLISHED%'
665 | AND p_size IN (
666 | 49,
667 | 14,
668 | 23,
669 | 45,
670 | 19,
671 | 3,
672 | 36,
673 | 9
674 | )
675 | AND ps_suppkey NOT IN (
676 | SELECT
677 | s_suppkey
678 | FROM
679 | supplier
680 | WHERE
681 | s_comment LIKE '%Customer%Complaints%'
682 | )
683 | GROUP BY
684 | p_brand,
685 | p_type,
686 | p_size
687 | ORDER BY
688 | supplier_cnt DESC,
689 | p_brand,
690 | p_type,
691 | p_size;
692 |
693 |
694 |
695 | ''').fetchdf()
696 | print(df)
697 |
698 |
699 | df =con.execute('''
700 | PRAGMA enable_profiling='json';
701 | PRAGMA profile_output='./json/17.json';
702 |
703 |
704 | SELECT
705 | --Query17
706 | SUM(l_extendedprice) / 7.0 AS avg_yearly
707 | FROM
708 | lineitem,
709 | part
710 | WHERE
711 | p_partkey = l_partkey
712 | AND p_brand = 'Brand#23'
713 | AND p_container = 'MED BOX'
714 | AND l_quantity < (
715 | SELECT
716 | 0.2 * AVG(l_quantity)
717 | FROM
718 | lineitem
719 | WHERE
720 | l_partkey = p_partkey
721 | );
722 |
723 | ''').fetchdf()
724 | print(df)
725 |
726 | df =con.execute('''
727 | PRAGMA enable_profiling='json';
728 | PRAGMA profile_output='./json/18.json';
729 |
730 |
731 | SELECT
732 | --Query18
733 | c_name,
734 | c_custkey,
735 | o_orderkey,
736 | o_orderdate,
737 | o_totalprice,
738 | SUM(l_quantity)
739 | FROM
740 | customer,
741 | orders,
742 | lineitem
743 | WHERE
744 | o_orderkey IN (
745 | SELECT
746 | l_orderkey
747 | FROM
748 | lineitem
749 | GROUP BY
750 | l_orderkey
751 | HAVING
752 | SUM(l_quantity) > 300
753 | )
754 | AND c_custkey = o_custkey
755 | AND o_orderkey = l_orderkey
756 | GROUP BY
757 | c_name,
758 | c_custkey,
759 | o_orderkey,
760 | o_orderdate,
761 | o_totalprice
762 | ORDER BY
763 | o_totalprice DESC,
764 | o_orderdate
765 | LIMIT
766 | 100;
767 |
768 | ''').fetchdf()
769 | print(df)
770 |
771 |
772 | df =con.execute('''
773 | PRAGMA enable_profiling='json';
774 | PRAGMA profile_output='./json/19.json';
775 |
776 |
777 | SELECT
778 | --Query19
779 | SUM(l_extendedprice * (1 - l_discount)) AS revenue
780 | FROM
781 | lineitem,
782 | part
783 | WHERE
784 | (
785 | p_partkey = l_partkey
786 | AND p_brand = 'Brand#12'
787 | AND p_container IN (
788 | 'SM CASE',
789 | 'SM BOX',
790 | 'SM PACK',
791 | 'SM PKG'
792 | )
793 | AND l_quantity >= 1
794 | AND l_quantity <= 1 + 10
795 | AND p_size BETWEEN 1
796 | AND 5
797 | AND l_shipmode IN ('AIR', 'AIR REG')
798 | AND l_shipinstruct = 'DELIVER IN PERSON'
799 | )
800 | OR (
801 | p_partkey = l_partkey
802 | AND p_brand = 'Brand#23'
803 | AND p_container IN (
804 | 'MED BAG',
805 | 'MED BOX',
806 | 'MED PKG',
807 | 'MED PACK'
808 | )
809 | AND l_quantity >= 10
810 | AND l_quantity <= 10 + 10
811 | AND p_size BETWEEN 1
812 | AND 10
813 | AND l_shipmode IN ('AIR', 'AIR REG')
814 | AND l_shipinstruct = 'DELIVER IN PERSON'
815 | )
816 | OR (
817 | p_partkey = l_partkey
818 | AND p_brand = 'Brand#34'
819 | AND p_container IN (
820 | 'LG CASE',
821 | 'LG BOX',
822 | 'LG PACK',
823 | 'LG PKG'
824 | )
825 | AND l_quantity >= 20
826 | AND l_quantity <= 20 + 10
827 | AND p_size BETWEEN 1
828 | AND 15
829 | AND l_shipmode IN ('AIR', 'AIR REG')
830 | AND l_shipinstruct = 'DELIVER IN PERSON'
831 | );
832 |
833 | ''').fetchdf()
834 | print(df)
835 |
836 |
837 | df =con.execute('''
838 | PRAGMA enable_profiling='json';
839 | PRAGMA profile_output='./json/20.json';
840 |
841 |
842 | SELECT
843 | --Query20
844 | s_name,
845 | s_address
846 | FROM
847 | supplier,
848 | nation
849 | WHERE
850 | s_suppkey IN (
851 | SELECT
852 | ps_suppkey
853 | FROM
854 | partsupp
855 | WHERE
856 | ps_partkey IN (
857 | SELECT
858 | p_partkey
859 | FROM
860 | part
861 | WHERE
862 | p_name LIKE 'forest%'
863 | )
864 | AND ps_availqty > (
865 | SELECT
866 | 0.5 * SUM(l_quantity)
867 | FROM
868 | lineitem
869 | WHERE
870 | l_partkey = ps_partkey
871 | AND l_suppkey = ps_suppkey
872 | AND l_shipdate >= CAST('1994-01-01' AS date)
873 | AND l_shipdate < CAST('1995-01-01' AS date)
874 | )
875 | )
876 | AND s_nationkey = n_nationkey
877 | AND n_name = 'CANADA'
878 | ORDER BY
879 | s_name;
880 |
881 | ''').fetchdf()
882 | print(df)
883 |
884 | df =con.execute('''
885 | PRAGMA enable_profiling='json';
886 | PRAGMA profile_output='./json/21.json';
887 |
888 |
889 | SELECT
890 | --Query21
891 | s_name,
892 | COUNT(*) AS numwait
893 | FROM
894 | supplier,
895 | lineitem l1,
896 | orders,
897 | nation
898 | WHERE
899 | s_suppkey = l1.l_suppkey
900 | AND o_orderkey = l1.l_orderkey
901 | AND o_orderstatus = 'F'
902 | AND l1.l_receiptdate > l1.l_commitdate
903 | AND EXISTS (
904 | SELECT
905 | *
906 | FROM
907 | lineitem l2
908 | WHERE
909 | l2.l_orderkey = l1.l_orderkey
910 | AND l2.l_suppkey <> l1.l_suppkey
911 | )
912 | AND NOT EXISTS (
913 | SELECT
914 | *
915 | FROM
916 | lineitem l3
917 | WHERE
918 | l3.l_orderkey = l1.l_orderkey
919 | AND l3.l_suppkey <> l1.l_suppkey
920 | AND l3.l_receiptdate > l3.l_commitdate
921 | )
922 | AND s_nationkey = n_nationkey
923 | AND n_name = 'SAUDI ARABIA'
924 | GROUP BY
925 | s_name
926 | ORDER BY
927 | numwait DESC,
928 | s_name
929 | LIMIT
930 | 100;
931 |
932 | ''').fetchdf()
933 | print(df)
934 |
935 | df =con.execute('''
936 | PRAGMA enable_profiling='json';
937 | PRAGMA profile_output='./json/22.json';
938 |
939 |
940 | SELECT
941 | --Query22
942 | cntrycode,
943 | COUNT(*) AS numcust,
944 | SUM(c_acctbal) AS totacctbal
945 | FROM
946 | (
947 | SELECT
948 | SUBSTRING(c_phone, 1, 2) AS cntrycode,
949 | c_acctbal
950 | FROM
951 | customer
952 | WHERE
953 | SUBSTRING(c_phone, 1, 2) IN (
954 | '13',
955 | '31',
956 | '23',
957 | '29',
958 | '30',
959 | '18',
960 | '17'
961 | )
962 | AND c_acctbal > (
963 | SELECT
964 | AVG(c_acctbal)
965 | FROM
966 | customer
967 | WHERE
968 | c_acctbal > 0.00
969 | AND SUBSTRING(c_phone, 1, 2) IN (
970 | '13',
971 | '31',
972 | '23',
973 | '29',
974 | '30',
975 | '18',
976 | '17'
977 | )
978 | )
979 | AND NOT EXISTS (
980 | SELECT
981 | *
982 | FROM
983 | orders
984 | WHERE
985 | o_custkey = c_custkey
986 | )
987 | ) AS custsale
988 | GROUP BY
989 | cntrycode
990 | ORDER BY
991 | cntrycode;
992 |
993 | ''').fetchdf()
994 | print(df)
995 |
--------------------------------------------------------------------------------
/Database/DuckDB/vertipaq.ipynb:
--------------------------------------------------------------------------------
1 | {
2 | "cells": [
3 | {
4 | "cell_type": "code",
5 | "execution_count": 2,
6 | "metadata": {},
7 | "outputs": [],
8 | "source": [
9 | "import duckdb \n",
10 | "con = duckdb.connect(database='C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/db/tpch',read_only=True)"
11 | ]
12 | },
13 | {
14 | "cell_type": "code",
15 | "execution_count": 8,
16 | "metadata": {},
17 | "outputs": [
18 | {
19 | "data": {
20 | "text/html": [
21 | "
\n",
22 | "\n",
35 | "
\n",
36 | " \n",
37 | " \n",
38 | " | \n",
39 | " L_ORDERKEY | \n",
40 | " sum_qty | \n",
41 | "
\n",
42 | " \n",
43 | " \n",
44 | " \n",
45 | " | 0 | \n",
46 | " 26465922 | \n",
47 | " 331.0 | \n",
48 | "
\n",
49 | " \n",
50 | " | 1 | \n",
51 | " 4806726 | \n",
52 | " 328.0 | \n",
53 | "
\n",
54 | " \n",
55 | " | 2 | \n",
56 | " 21213895 | \n",
57 | " 327.0 | \n",
58 | "
\n",
59 | " \n",
60 | " | 3 | \n",
61 | " 46685344 | \n",
62 | " 327.0 | \n",
63 | "
\n",
64 | " \n",
65 | " | 4 | \n",
66 | " 48881602 | \n",
67 | " 327.0 | \n",
68 | "
\n",
69 | " \n",
70 | " | ... | \n",
71 | " ... | \n",
72 | " ... | \n",
73 | "
\n",
74 | " \n",
75 | " | 496 | \n",
76 | " 30338976 | \n",
77 | " 303.0 | \n",
78 | "
\n",
79 | " \n",
80 | " | 497 | \n",
81 | " 57968195 | \n",
82 | " 303.0 | \n",
83 | "
\n",
84 | " \n",
85 | " | 498 | \n",
86 | " 13841255 | \n",
87 | " 302.0 | \n",
88 | "
\n",
89 | " \n",
90 | " | 499 | \n",
91 | " 17612003 | \n",
92 | " 302.0 | \n",
93 | "
\n",
94 | " \n",
95 | " | 500 | \n",
96 | " 52679876 | \n",
97 | " 302.0 | \n",
98 | "
\n",
99 | " \n",
100 | "
\n",
101 | "
501 rows × 2 columns
\n",
102 | "
"
103 | ],
104 | "text/plain": [
105 | " L_ORDERKEY sum_qty\n",
106 | "0 26465922 331.0\n",
107 | "1 4806726 328.0\n",
108 | "2 21213895 327.0\n",
109 | "3 46685344 327.0\n",
110 | "4 48881602 327.0\n",
111 | ".. ... ...\n",
112 | "496 30338976 303.0\n",
113 | "497 57968195 303.0\n",
114 | "498 13841255 302.0\n",
115 | "499 17612003 302.0\n",
116 | "500 52679876 302.0\n",
117 | "\n",
118 | "[501 rows x 2 columns]"
119 | ]
120 | },
121 | "execution_count": 8,
122 | "metadata": {},
123 | "output_type": "execute_result"
124 | }
125 | ],
126 | "source": [
127 | "xx = con.execute('''\n",
128 | "\n",
129 | "SELECT\n",
130 | " L_orderkey, \n",
131 | " SUM(l_quantity) AS sum_qty\n",
132 | "FROM\n",
133 | " lineitem\n",
134 | "GROUP BY\n",
135 | " 1\n",
136 | "ORDER BY\n",
137 | " 2 desc\n",
138 | " limit 501 ; \n",
139 | "''').df()\n",
140 | "xx"
141 | ]
142 | },
143 | {
144 | "cell_type": "code",
145 | "execution_count": 9,
146 | "metadata": {},
147 | "outputs": [
148 | {
149 | "data": {
150 | "text/html": [
151 | "\n",
152 | "\n",
165 | "
\n",
166 | " \n",
167 | " \n",
168 | " | \n",
169 | " L_RETURNFLAG | \n",
170 | " L_LINESTATUS | \n",
171 | " sum_qty | \n",
172 | " sum_base_price | \n",
173 | " sum_disc_price | \n",
174 | " sum_charge | \n",
175 | " avg_qty | \n",
176 | " avg_price | \n",
177 | " avg_disc | \n",
178 | "
\n",
179 | " \n",
180 | " \n",
181 | " \n",
182 | " | 0 | \n",
183 | " A | \n",
184 | " F | \n",
185 | " 377518399.0 | \n",
186 | " 5.660657e+11 | \n",
187 | " 5.377591e+11 | \n",
188 | " 5.592767e+11 | \n",
189 | " 25.500975 | \n",
190 | " 38237.151009 | \n",
191 | " 0.050007 | \n",
192 | "
\n",
193 | " \n",
194 | " | 1 | \n",
195 | " N | \n",
196 | " F | \n",
197 | " 9851614.0 | \n",
198 | " 1.476744e+10 | \n",
199 | " 1.402881e+10 | \n",
200 | " 1.459049e+10 | \n",
201 | " 25.522448 | \n",
202 | " 38257.810660 | \n",
203 | " 0.049973 | \n",
204 | "
\n",
205 | " \n",
206 | " | 2 | \n",
207 | " N | \n",
208 | " O | \n",
209 | " 764635193.0 | \n",
210 | " 1.146549e+12 | \n",
211 | " 1.089216e+12 | \n",
212 | " 1.132797e+12 | \n",
213 | " 25.498214 | \n",
214 | " 38233.853934 | \n",
215 | " 0.050001 | \n",
216 | "
\n",
217 | " \n",
218 | " | 3 | \n",
219 | " R | \n",
220 | " F | \n",
221 | " 377732830.0 | \n",
222 | " 5.664311e+11 | \n",
223 | " 5.381109e+11 | \n",
224 | " 5.596348e+11 | \n",
225 | " 25.508385 | \n",
226 | " 38251.219274 | \n",
227 | " 0.049997 | \n",
228 | "
\n",
229 | " \n",
230 | "
\n",
231 | "
"
232 | ],
233 | "text/plain": [
234 | " L_RETURNFLAG L_LINESTATUS sum_qty sum_base_price sum_disc_price \\\n",
235 | "0 A F 377518399.0 5.660657e+11 5.377591e+11 \n",
236 | "1 N F 9851614.0 1.476744e+10 1.402881e+10 \n",
237 | "2 N O 764635193.0 1.146549e+12 1.089216e+12 \n",
238 | "3 R F 377732830.0 5.664311e+11 5.381109e+11 \n",
239 | "\n",
240 | " sum_charge avg_qty avg_price avg_disc \n",
241 | "0 5.592767e+11 25.500975 38237.151009 0.050007 \n",
242 | "1 1.459049e+10 25.522448 38257.810660 0.049973 \n",
243 | "2 1.132797e+12 25.498214 38233.853934 0.050001 \n",
244 | "3 5.596348e+11 25.508385 38251.219274 0.049997 "
245 | ]
246 | },
247 | "execution_count": 9,
248 | "metadata": {},
249 | "output_type": "execute_result"
250 | }
251 | ],
252 | "source": [
253 | "# Lineitem has 60 million records\n",
254 | "xx = con.execute('''\n",
255 | "SELECT\n",
256 | " l_returnflag,\n",
257 | " l_linestatus,\n",
258 | " SUM(l_quantity) AS sum_qty,\n",
259 | " SUM(l_extendedprice) AS sum_base_price,\n",
260 | " SUM(l_extendedprice * (1 - l_discount)) AS sum_disc_price,\n",
261 | " SUM(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge,\n",
262 | " AVG(l_quantity) AS avg_qty,\n",
263 | " AVG(l_extendedprice) AS avg_price,\n",
264 | " AVG(l_discount) AS avg_disc\n",
265 | "FROM\n",
266 | " lineitem\n",
267 | "GROUP BY\n",
268 | " l_returnflag,\n",
269 | " l_linestatus\n",
270 | "ORDER BY\n",
271 | " l_returnflag,\n",
272 | " l_linestatus;\n",
273 | " ''').df()\n",
274 | "xx"
275 | ]
276 | },
277 | {
278 | "cell_type": "code",
279 | "execution_count": 15,
280 | "metadata": {},
281 | "outputs": [
282 | {
283 | "data": {
284 | "text/html": [
285 | "\n",
286 | "\n",
299 | "
\n",
300 | " \n",
301 | " \n",
302 | " | \n",
303 | " C_NAME | \n",
304 | " sum_qty | \n",
305 | "
\n",
306 | " \n",
307 | " \n",
308 | " \n",
309 | " | 0 | \n",
310 | " Customer#000317698 | \n",
311 | " 4880.0 | \n",
312 | "
\n",
313 | " \n",
314 | " | 1 | \n",
315 | " Customer#000694366 | \n",
316 | " 4756.0 | \n",
317 | "
\n",
318 | " \n",
319 | " | 2 | \n",
320 | " Customer#000910705 | \n",
321 | " 4731.0 | \n",
322 | "
\n",
323 | " \n",
324 | " | 3 | \n",
325 | " Customer#000750415 | \n",
326 | " 4716.0 | \n",
327 | "
\n",
328 | " \n",
329 | " | 4 | \n",
330 | " Customer#000359587 | \n",
331 | " 4706.0 | \n",
332 | "
\n",
333 | " \n",
334 | " | ... | \n",
335 | " ... | \n",
336 | " ... | \n",
337 | "
\n",
338 | " \n",
339 | " | 496 | \n",
340 | " Customer#000684004 | \n",
341 | " 3873.0 | \n",
342 | "
\n",
343 | " \n",
344 | " | 497 | \n",
345 | " Customer#000924955 | \n",
346 | " 3871.0 | \n",
347 | "
\n",
348 | " \n",
349 | " | 498 | \n",
350 | " Customer#001432723 | \n",
351 | " 3870.0 | \n",
352 | "
\n",
353 | " \n",
354 | " | 499 | \n",
355 | " Customer#001008862 | \n",
356 | " 3870.0 | \n",
357 | "
\n",
358 | " \n",
359 | " | 500 | \n",
360 | " Customer#001363525 | \n",
361 | " 3869.0 | \n",
362 | "
\n",
363 | " \n",
364 | "
\n",
365 | "
501 rows × 2 columns
\n",
366 | "
"
367 | ],
368 | "text/plain": [
369 | " C_NAME sum_qty\n",
370 | "0 Customer#000317698 4880.0\n",
371 | "1 Customer#000694366 4756.0\n",
372 | "2 Customer#000910705 4731.0\n",
373 | "3 Customer#000750415 4716.0\n",
374 | "4 Customer#000359587 4706.0\n",
375 | ".. ... ...\n",
376 | "496 Customer#000684004 3873.0\n",
377 | "497 Customer#000924955 3871.0\n",
378 | "498 Customer#001432723 3870.0\n",
379 | "499 Customer#001008862 3870.0\n",
380 | "500 Customer#001363525 3869.0\n",
381 | "\n",
382 | "[501 rows x 2 columns]"
383 | ]
384 | },
385 | "execution_count": 15,
386 | "metadata": {},
387 | "output_type": "execute_result"
388 | }
389 | ],
390 | "source": [
391 | "xx=con.execute('''\n",
392 | "\n",
393 | "SELECT \n",
394 | " customer_0.\"C_NAME\" as \"C_NAME\",\n",
395 | " COALESCE(SUM(lineitem.\"L_QUANTITY\"),0) as \"sum_qty\"\n",
396 | "FROM '/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/lineitem.parquet' as lineitem\n",
397 | "LEFT JOIN '/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/orders.parquet' AS orders_0\n",
398 | " ON orders_0.\"O_ORDERKEY\"=lineitem.\"L_ORDERKEY\"\n",
399 | "LEFT JOIN '/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/customer.parquet' AS customer_0\n",
400 | " ON customer_0.\"C_CUSTKEY\"=orders_0.\"O_CUSTKEY\"\n",
401 | "GROUP BY 1\n",
402 | "ORDER BY 2 desc NULLS LAST\n",
403 | "LIMIT 501 ;\n",
404 | " ''').df()\n",
405 | "xx"
406 | ]
407 | },
408 | {
409 | "cell_type": "code",
410 | "execution_count": 5,
411 | "metadata": {},
412 | "outputs": [
413 | {
414 | "data": {
415 | "text/html": [
416 | "\n",
417 | "\n",
430 | "
\n",
431 | " \n",
432 | " \n",
433 | " | \n",
434 | " L_COMMENT | \n",
435 | " sum_qty | \n",
436 | " sum_base_price | \n",
437 | " sum_disc_price | \n",
438 | " sum_charge | \n",
439 | " avg_qty | \n",
440 | " avg_price | \n",
441 | " avg_disc | \n",
442 | "
\n",
443 | " \n",
444 | " \n",
445 | " \n",
446 | " | 0 | \n",
447 | " carefully | \n",
448 | " 233132.0 | \n",
449 | " 3.494738e+08 | \n",
450 | " 3.319834e+08 | \n",
451 | " 3.452452e+08 | \n",
452 | " 25.481692 | \n",
453 | " 38198.034950 | \n",
454 | " 0.050141 | \n",
455 | "
\n",
456 | " \n",
457 | " | 1 | \n",
458 | " carefully | \n",
459 | " 215171.0 | \n",
460 | " 3.218755e+08 | \n",
461 | " 3.057257e+08 | \n",
462 | " 3.181725e+08 | \n",
463 | " 25.361975 | \n",
464 | " 37939.115077 | \n",
465 | " 0.049894 | \n",
466 | "
\n",
467 | " \n",
468 | " | 2 | \n",
469 | " carefully | \n",
470 | " 213553.0 | \n",
471 | " 3.195423e+08 | \n",
472 | " 3.034478e+08 | \n",
473 | " 3.156221e+08 | \n",
474 | " 25.380675 | \n",
475 | " 37977.459308 | \n",
476 | " 0.050203 | \n",
477 | "
\n",
478 | " \n",
479 | " | 3 | \n",
480 | " e carefully | \n",
481 | " 104628.0 | \n",
482 | " 1.560138e+08 | \n",
483 | " 1.481716e+08 | \n",
484 | " 1.541446e+08 | \n",
485 | " 25.994534 | \n",
486 | " 38761.190435 | \n",
487 | " 0.050092 | \n",
488 | "
\n",
489 | " \n",
490 | " | 4 | \n",
491 | " e carefully | \n",
492 | " 88948.0 | \n",
493 | " 1.334310e+08 | \n",
494 | " 1.267860e+08 | \n",
495 | " 1.318291e+08 | \n",
496 | " 25.559770 | \n",
497 | " 38342.237221 | \n",
498 | " 0.049770 | \n",
499 | "
\n",
500 | " \n",
501 | " | ... | \n",
502 | " ... | \n",
503 | " ... | \n",
504 | " ... | \n",
505 | " ... | \n",
506 | " ... | \n",
507 | " ... | \n",
508 | " ... | \n",
509 | " ... | \n",
510 | "
\n",
511 | " \n",
512 | " | 496 | \n",
513 | " ost carefully | \n",
514 | " 5252.0 | \n",
515 | " 7.634618e+06 | \n",
516 | " 7.277658e+06 | \n",
517 | " 7.606470e+06 | \n",
518 | " 24.427907 | \n",
519 | " 35509.849721 | \n",
520 | " 0.047860 | \n",
521 | "
\n",
522 | " \n",
523 | " | 497 | \n",
524 | " ross the carefully | \n",
525 | " 5249.0 | \n",
526 | " 7.828127e+06 | \n",
527 | " 7.441797e+06 | \n",
528 | " 7.751023e+06 | \n",
529 | " 27.056701 | \n",
530 | " 40351.171186 | \n",
531 | " 0.048454 | \n",
532 | "
\n",
533 | " \n",
534 | " | 498 | \n",
535 | " the carefully s | \n",
536 | " 5238.0 | \n",
537 | " 8.082824e+06 | \n",
538 | " 7.690452e+06 | \n",
539 | " 8.030897e+06 | \n",
540 | " 25.304348 | \n",
541 | " 39047.461014 | \n",
542 | " 0.049662 | \n",
543 | "
\n",
544 | " \n",
545 | " | 499 | \n",
546 | " ages. carefully | \n",
547 | " 5233.0 | \n",
548 | " 7.940068e+06 | \n",
549 | " 7.533151e+06 | \n",
550 | " 7.838192e+06 | \n",
551 | " 23.572072 | \n",
552 | " 35766.074144 | \n",
553 | " 0.050045 | \n",
554 | "
\n",
555 | " \n",
556 | " | 500 | \n",
557 | " e. carefully | \n",
558 | " 5233.0 | \n",
559 | " 7.645475e+06 | \n",
560 | " 7.267714e+06 | \n",
561 | " 7.550702e+06 | \n",
562 | " 25.905941 | \n",
563 | " 37848.888218 | \n",
564 | " 0.048515 | \n",
565 | "
\n",
566 | " \n",
567 | "
\n",
568 | "
501 rows × 8 columns
\n",
569 | "
"
570 | ],
571 | "text/plain": [
572 | " L_COMMENT sum_qty sum_base_price sum_disc_price \\\n",
573 | "0 carefully 233132.0 3.494738e+08 3.319834e+08 \n",
574 | "1 carefully 215171.0 3.218755e+08 3.057257e+08 \n",
575 | "2 carefully 213553.0 3.195423e+08 3.034478e+08 \n",
576 | "3 e carefully 104628.0 1.560138e+08 1.481716e+08 \n",
577 | "4 e carefully 88948.0 1.334310e+08 1.267860e+08 \n",
578 | ".. ... ... ... ... \n",
579 | "496 ost carefully 5252.0 7.634618e+06 7.277658e+06 \n",
580 | "497 ross the carefully 5249.0 7.828127e+06 7.441797e+06 \n",
581 | "498 the carefully s 5238.0 8.082824e+06 7.690452e+06 \n",
582 | "499 ages. carefully 5233.0 7.940068e+06 7.533151e+06 \n",
583 | "500 e. carefully 5233.0 7.645475e+06 7.267714e+06 \n",
584 | "\n",
585 | " sum_charge avg_qty avg_price avg_disc \n",
586 | "0 3.452452e+08 25.481692 38198.034950 0.050141 \n",
587 | "1 3.181725e+08 25.361975 37939.115077 0.049894 \n",
588 | "2 3.156221e+08 25.380675 37977.459308 0.050203 \n",
589 | "3 1.541446e+08 25.994534 38761.190435 0.050092 \n",
590 | "4 1.318291e+08 25.559770 38342.237221 0.049770 \n",
591 | ".. ... ... ... ... \n",
592 | "496 7.606470e+06 24.427907 35509.849721 0.047860 \n",
593 | "497 7.751023e+06 27.056701 40351.171186 0.048454 \n",
594 | "498 8.030897e+06 25.304348 39047.461014 0.049662 \n",
595 | "499 7.838192e+06 23.572072 35766.074144 0.050045 \n",
596 | "500 7.550702e+06 25.905941 37848.888218 0.048515 \n",
597 | "\n",
598 | "[501 rows x 8 columns]"
599 | ]
600 | },
601 | "execution_count": 5,
602 | "metadata": {},
603 | "output_type": "execute_result"
604 | }
605 | ],
606 | "source": [
607 | "# the table is 60 million records, with 33 million unique text \n",
608 | "xx = con.execute('''\n",
609 | "SELECT\n",
610 | " l_comment,\n",
611 | " SUM(l_quantity) AS sum_qty,\n",
612 | " SUM(l_extendedprice) AS sum_base_price,\n",
613 | " SUM(l_extendedprice * (1 - l_discount)) AS sum_disc_price,\n",
614 | " SUM(l_extendedprice * (1 - l_discount) * (1 + l_tax)) AS sum_charge,\n",
615 | " AVG(l_quantity) AS avg_qty,\n",
616 | " AVG(l_extendedprice) AS avg_price,\n",
617 | " AVG(l_discount) AS avg_disc\n",
618 | "FROM\n",
619 | " lineitem\n",
620 | "where l_comment like '%carefully%'\n",
621 | "GROUP BY\n",
622 | " all\n",
623 | "ORDER BY\n",
624 | " 2 desc\n",
625 | "limit 501 ;\n",
626 | " ''').df()\n",
627 | "xx"
628 | ]
629 | },
630 | {
631 | "cell_type": "code",
632 | "execution_count": 6,
633 | "metadata": {},
634 | "outputs": [
635 | {
636 | "data": {
637 | "text/html": [
638 | "\n",
639 | "\n",
652 | "
\n",
653 | " \n",
654 | " \n",
655 | " | \n",
656 | " count(DISTINCT \"L_orderkey\") | \n",
657 | "
\n",
658 | " \n",
659 | " \n",
660 | " \n",
661 | " | 0 | \n",
662 | " 15000000 | \n",
663 | "
\n",
664 | " \n",
665 | "
\n",
666 | "
"
667 | ],
668 | "text/plain": [
669 | " count(DISTINCT \"L_orderkey\")\n",
670 | "0 15000000"
671 | ]
672 | },
673 | "execution_count": 6,
674 | "metadata": {},
675 | "output_type": "execute_result"
676 | }
677 | ],
678 | "source": [
679 | " \n",
680 | "xx = con.execute('''\n",
681 | "\n",
682 | "SELECT\n",
683 | " \n",
684 | " count (distinct L_orderkey)\n",
685 | " \n",
686 | "FROM\n",
687 | " lineitem\n",
688 | "\n",
689 | " ;\n",
690 | " ''').df()\n",
691 | "xx"
692 | ]
693 | },
694 | {
695 | "cell_type": "code",
696 | "execution_count": 32,
697 | "metadata": {},
698 | "outputs": [
699 | {
700 | "data": {
701 | "text/html": [
702 | "\n",
703 | "\n",
716 | "
\n",
717 | " \n",
718 | " \n",
719 | " | \n",
720 | " L_SHIPDATE | \n",
721 | " count(DISTINCT \"L_orderkey\") | \n",
722 | "
\n",
723 | " \n",
724 | " \n",
725 | " \n",
726 | " | 0 | \n",
727 | " 1993-07-10 | \n",
728 | " 25083 | \n",
729 | "
\n",
730 | " \n",
731 | " | 1 | \n",
732 | " 1997-04-18 | \n",
733 | " 25029 | \n",
734 | "
\n",
735 | " \n",
736 | " | 2 | \n",
737 | " 1993-05-17 | \n",
738 | " 25008 | \n",
739 | "
\n",
740 | " \n",
741 | " | 3 | \n",
742 | " 1994-01-17 | \n",
743 | " 24998 | \n",
744 | "
\n",
745 | " \n",
746 | " | 4 | \n",
747 | " 1993-04-01 | \n",
748 | " 24985 | \n",
749 | "
\n",
750 | " \n",
751 | " | ... | \n",
752 | " ... | \n",
753 | " ... | \n",
754 | "
\n",
755 | " \n",
756 | " | 2521 | \n",
757 | " 1998-11-29 | \n",
758 | " 583 | \n",
759 | "
\n",
760 | " \n",
761 | " | 2522 | \n",
762 | " 1992-01-03 | \n",
763 | " 405 | \n",
764 | "
\n",
765 | " \n",
766 | " | 2523 | \n",
767 | " 1998-11-30 | \n",
768 | " 402 | \n",
769 | "
\n",
770 | " \n",
771 | " | 2524 | \n",
772 | " 1998-12-01 | \n",
773 | " 214 | \n",
774 | "
\n",
775 | " \n",
776 | " | 2525 | \n",
777 | " 1992-01-02 | \n",
778 | " 192 | \n",
779 | "
\n",
780 | " \n",
781 | "
\n",
782 | "
2526 rows × 2 columns
\n",
783 | "
"
784 | ],
785 | "text/plain": [
786 | " L_SHIPDATE count(DISTINCT \"L_orderkey\")\n",
787 | "0 1993-07-10 25083\n",
788 | "1 1997-04-18 25029\n",
789 | "2 1993-05-17 25008\n",
790 | "3 1994-01-17 24998\n",
791 | "4 1993-04-01 24985\n",
792 | "... ... ...\n",
793 | "2521 1998-11-29 583\n",
794 | "2522 1992-01-03 405\n",
795 | "2523 1998-11-30 402\n",
796 | "2524 1998-12-01 214\n",
797 | "2525 1992-01-02 192\n",
798 | "\n",
799 | "[2526 rows x 2 columns]"
800 | ]
801 | },
802 | "execution_count": 32,
803 | "metadata": {},
804 | "output_type": "execute_result"
805 | }
806 | ],
807 | "source": [
808 | "# the table is 60 million records, with 33 million unique text \n",
809 | "xx = con.execute('''\n",
810 | "\n",
811 | "SELECT\n",
812 | " l_shipdate ,\n",
813 | " count (distinct L_orderkey),\n",
814 | " \n",
815 | "FROM\n",
816 | " lineitem\n",
817 | "group by 1\n",
818 | "order by 2 desc \n",
819 | " ;\n",
820 | " ''').df()\n",
821 | "xx"
822 | ]
823 | },
824 | {
825 | "cell_type": "code",
826 | "execution_count": 7,
827 | "metadata": {},
828 | "outputs": [
829 | {
830 | "data": {
831 | "text/html": [
832 | "\n",
833 | "\n",
846 | "
\n",
847 | " \n",
848 | " \n",
849 | " | \n",
850 | " L_COMMENT | \n",
851 | " count(DISTINCT \"L_orderkey\") | \n",
852 | "
\n",
853 | " \n",
854 | " \n",
855 | " \n",
856 | " | 0 | \n",
857 | " furiously | \n",
858 | " 9519 | \n",
859 | "
\n",
860 | " \n",
861 | " | 1 | \n",
862 | " carefully | \n",
863 | " 9144 | \n",
864 | "
\n",
865 | " \n",
866 | " | 2 | \n",
867 | " carefully | \n",
868 | " 8483 | \n",
869 | "
\n",
870 | " \n",
871 | " | 3 | \n",
872 | " furiously | \n",
873 | " 8475 | \n",
874 | "
\n",
875 | " \n",
876 | " | 4 | \n",
877 | " carefully | \n",
878 | " 8411 | \n",
879 | "
\n",
880 | " \n",
881 | " | 5 | \n",
882 | " furiously | \n",
883 | " 8410 | \n",
884 | "
\n",
885 | " \n",
886 | " | 6 | \n",
887 | " blithely | \n",
888 | " 6633 | \n",
889 | "
\n",
890 | " \n",
891 | " | 7 | \n",
892 | " ly regular | \n",
893 | " 6030 | \n",
894 | "
\n",
895 | " \n",
896 | " | 8 | \n",
897 | " ly regular | \n",
898 | " 5751 | \n",
899 | "
\n",
900 | " \n",
901 | " | 9 | \n",
902 | " y regular | \n",
903 | " 5639 | \n",
904 | "
\n",
905 | " \n",
906 | "
\n",
907 | "
"
908 | ],
909 | "text/plain": [
910 | " L_COMMENT count(DISTINCT \"L_orderkey\")\n",
911 | "0 furiously 9519\n",
912 | "1 carefully 9144\n",
913 | "2 carefully 8483\n",
914 | "3 furiously 8475\n",
915 | "4 carefully 8411\n",
916 | "5 furiously 8410\n",
917 | "6 blithely 6633\n",
918 | "7 ly regular 6030\n",
919 | "8 ly regular 5751\n",
920 | "9 y regular 5639"
921 | ]
922 | },
923 | "execution_count": 7,
924 | "metadata": {},
925 | "output_type": "execute_result"
926 | }
927 | ],
928 | "source": [
929 | "xx = con.execute('''\n",
930 | "\n",
931 | "SELECT\n",
932 | " l_comment ,\n",
933 | " count (distinct L_orderkey),\n",
934 | " \n",
935 | "FROM\n",
936 | " lineitem\n",
937 | "group by 1\n",
938 | "order by 2 desc \n",
939 | "limit 10\n",
940 | " ;\n",
941 | " ''').df()\n",
942 | "xx"
943 | ]
944 | },
945 | {
946 | "cell_type": "code",
947 | "execution_count": 11,
948 | "metadata": {},
949 | "outputs": [
950 | {
951 | "data": {
952 | "text/html": [
953 | "\n",
954 | "\n",
967 | "
\n",
968 | " \n",
969 | " \n",
970 | " | \n",
971 | " R_NAME | \n",
972 | " sum_qty | \n",
973 | "
\n",
974 | " \n",
975 | " \n",
976 | " \n",
977 | " | 0 | \n",
978 | " EUROPE | \n",
979 | " 306686205.0 | \n",
980 | "
\n",
981 | " \n",
982 | " | 1 | \n",
983 | " ASIA | \n",
984 | " 306573761.0 | \n",
985 | "
\n",
986 | " \n",
987 | " | 2 | \n",
988 | " AFRICA | \n",
989 | " 305691519.0 | \n",
990 | "
\n",
991 | " \n",
992 | " | 3 | \n",
993 | " MIDDLE EAST | \n",
994 | " 305553071.0 | \n",
995 | "
\n",
996 | " \n",
997 | " | 4 | \n",
998 | " AMERICA | \n",
999 | " 305233480.0 | \n",
1000 | "
\n",
1001 | " \n",
1002 | "
\n",
1003 | "
"
1004 | ],
1005 | "text/plain": [
1006 | " R_NAME sum_qty\n",
1007 | "0 EUROPE 306686205.0\n",
1008 | "1 ASIA 306573761.0\n",
1009 | "2 AFRICA 305691519.0\n",
1010 | "3 MIDDLE EAST 305553071.0\n",
1011 | "4 AMERICA 305233480.0"
1012 | ]
1013 | },
1014 | "execution_count": 11,
1015 | "metadata": {},
1016 | "output_type": "execute_result"
1017 | }
1018 | ],
1019 | "source": [
1020 | "xx = con.execute('''\n",
1021 | "SELECT \n",
1022 | " customer_region_0.\"R_NAME\" as \"R_NAME\",\n",
1023 | " COALESCE(SUM(lineitem.\"L_QUANTITY\"),0) as \"sum_qty\"\n",
1024 | "FROM '/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/lineitem.parquet' as lineitem\n",
1025 | "LEFT JOIN '/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/orders.parquet' AS orders_0\n",
1026 | " ON orders_0.\"O_ORDERKEY\"=lineitem.\"L_ORDERKEY\"\n",
1027 | "LEFT JOIN '/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/customer.parquet' AS customer_0\n",
1028 | " ON customer_0.\"C_CUSTKEY\"=orders_0.\"O_CUSTKEY\"\n",
1029 | "LEFT JOIN '/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/nation.parquet' AS customer_nation_0\n",
1030 | " ON customer_nation_0.\"N_NATIONKEY\"=customer_0.\"C_NATIONKEY\"\n",
1031 | "LEFT JOIN '/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/region.parquet' AS customer_region_0\n",
1032 | " ON customer_region_0.\"R_REGIONKEY\"=customer_nation_0.\"N_REGIONKEY\"\n",
1033 | "GROUP BY 1\n",
1034 | "ORDER BY 2 desc NULLS LAST\n",
1035 | " ''').df()\n",
1036 | "xx"
1037 | ]
1038 | },
1039 | {
1040 | "cell_type": "code",
1041 | "execution_count": 9,
1042 | "metadata": {},
1043 | "outputs": [
1044 | {
1045 | "data": {
1046 | "text/html": [
1047 | "\n",
1048 | "\n",
1061 | "
\n",
1062 | " \n",
1063 | " \n",
1064 | " | \n",
1065 | " L_COMMENT | \n",
1066 | " count(DISTINCT \"L_orderkey\") | \n",
1067 | "
\n",
1068 | " \n",
1069 | " \n",
1070 | " \n",
1071 | " | 0 | \n",
1072 | " furiously | \n",
1073 | " 9519 | \n",
1074 | "
\n",
1075 | " \n",
1076 | " | 1 | \n",
1077 | " carefully | \n",
1078 | " 9144 | \n",
1079 | "
\n",
1080 | " \n",
1081 | " | 2 | \n",
1082 | " carefully | \n",
1083 | " 8483 | \n",
1084 | "
\n",
1085 | " \n",
1086 | " | 3 | \n",
1087 | " furiously | \n",
1088 | " 8475 | \n",
1089 | "
\n",
1090 | " \n",
1091 | " | 4 | \n",
1092 | " carefully | \n",
1093 | " 8411 | \n",
1094 | "
\n",
1095 | " \n",
1096 | " | 5 | \n",
1097 | " furiously | \n",
1098 | " 8410 | \n",
1099 | "
\n",
1100 | " \n",
1101 | " | 6 | \n",
1102 | " blithely | \n",
1103 | " 6633 | \n",
1104 | "
\n",
1105 | " \n",
1106 | " | 7 | \n",
1107 | " ly regular | \n",
1108 | " 6030 | \n",
1109 | "
\n",
1110 | " \n",
1111 | " | 8 | \n",
1112 | " ly regular | \n",
1113 | " 5751 | \n",
1114 | "
\n",
1115 | " \n",
1116 | " | 9 | \n",
1117 | " y regular | \n",
1118 | " 5639 | \n",
1119 | "
\n",
1120 | " \n",
1121 | "
\n",
1122 | "
"
1123 | ],
1124 | "text/plain": [
1125 | " L_COMMENT count(DISTINCT \"L_orderkey\")\n",
1126 | "0 furiously 9519\n",
1127 | "1 carefully 9144\n",
1128 | "2 carefully 8483\n",
1129 | "3 furiously 8475\n",
1130 | "4 carefully 8411\n",
1131 | "5 furiously 8410\n",
1132 | "6 blithely 6633\n",
1133 | "7 ly regular 6030\n",
1134 | "8 ly regular 5751\n",
1135 | "9 y regular 5639"
1136 | ]
1137 | },
1138 | "execution_count": 9,
1139 | "metadata": {},
1140 | "output_type": "execute_result"
1141 | }
1142 | ],
1143 | "source": [
1144 | "import duckdb \n",
1145 | "con = duckdb.connect()\n",
1146 | "xx = con.execute('''\n",
1147 | "\n",
1148 | "SELECT\n",
1149 | " l_comment ,\n",
1150 | " count (distinct L_orderkey),\n",
1151 | " \n",
1152 | "FROM 'C:/Users/mimoune.djouallah/Desktop/TPC-H-SF10/Parquet/lineitem/*.parquet'\n",
1153 | "group by 1\n",
1154 | "order by 2 desc \n",
1155 | "limit 10\n",
1156 | " ;\n",
1157 | " ''').df()\n",
1158 | "xx"
1159 | ]
1160 | }
1161 | ],
1162 | "metadata": {
1163 | "kernelspec": {
1164 | "display_name": "Python 3.7.4 64-bit (system)",
1165 | "language": "python",
1166 | "name": "python3"
1167 | },
1168 | "language_info": {
1169 | "codemirror_mode": {
1170 | "name": "ipython",
1171 | "version": 3
1172 | },
1173 | "file_extension": ".py",
1174 | "mimetype": "text/x-python",
1175 | "name": "python",
1176 | "nbconvert_exporter": "python",
1177 | "pygments_lexer": "ipython3",
1178 | "version": "3.7.4"
1179 | },
1180 | "orig_nbformat": 4,
1181 | "vscode": {
1182 | "interpreter": {
1183 | "hash": "7bd9e7efb6a75100408ddfb69d7c1262d756eda87c38ad89179993e0cd08f6f1"
1184 | }
1185 | }
1186 | },
1187 | "nbformat": 4,
1188 | "nbformat_minor": 2
1189 | }
1190 |
--------------------------------------------------------------------------------
/Database/Sorting/testing_sort in Fabric.ipynb:
--------------------------------------------------------------------------------
1 | {"cells":[{"cell_type":"markdown","source":["# Install Packages"],"metadata":{"id":"XwpvNhRHBWQf"}},{"cell_type":"code","source":["!pip install duckdb --pre --upgrade \n","!pip install polars --upgrade \n","!pip install datafusion "],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":3,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:20:55.2905278Z","session_start_time":"2023-06-15T05:20:55.6457552Z","execution_start_time":"2023-06-15T05:21:04.7855355Z","execution_finish_time":"2023-06-15T05:21:19.5468217Z","spark_jobs":{"numbers":{"SUCCEEDED":0,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"b41ee3c0-d209-41cf-8595-92c7d9953a88"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 3, Finished, Available)"},"metadata":{}},{"output_type":"stream","name":"stdout","text":["Collecting duckdb\n Downloading duckdb-0.8.2.dev1-cp310-cp310-manylinux_2_17_x86_64.manylinux2014_x86_64.whl (15.9 MB)\n\u001b[2K \u001b[90m━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━\u001b[0m \u001b[32m15.9/15.9 MB\u001b[0m \u001b[31m144.2 MB/s\u001b[0m eta \u001b[36m0:00:00\u001b[0m00:01\u001b[0m00:01\u001b[0m\n\u001b[?25hInstalling collected packages: duckdb\nSuccessfully installed duckdb-0.8.2.dev1\nCollecting polars\n Downloading polars-0.18.2-cp37-abi3-manylinux_2_17_x86_64.manylinux2014_x86_64.whl (18.6 MB)\n\u001b[2K \u001b[90m━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━\u001b[0m \u001b[32m18.6/18.6 MB\u001b[0m \u001b[31m125.3 MB/s\u001b[0m eta \u001b[36m0:00:00\u001b[0m00:01\u001b[0m00:01\u001b[0m\n\u001b[?25hInstalling collected packages: polars\nSuccessfully installed polars-0.18.2\nCollecting datafusion\n Downloading datafusion-25.0.0-cp37-abi3-manylinux_2_17_x86_64.manylinux2014_x86_64.whl (16.2 MB)\n\u001b[2K \u001b[90m━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━━\u001b[0m \u001b[32m16.2/16.2 MB\u001b[0m \u001b[31m115.5 MB/s\u001b[0m eta \u001b[36m0:00:00\u001b[0m00:01\u001b[0m00:01\u001b[0m\n\u001b[?25hRequirement already satisfied: pyarrow>=11.0.0 in /home/trusted-service-user/cluster-env/trident_env/lib/python3.10/site-packages (from datafusion) (11.0.0)\nRequirement already satisfied: numpy>=1.16.6 in /home/trusted-service-user/cluster-env/trident_env/lib/python3.10/site-packages (from pyarrow>=11.0.0->datafusion) (1.23.5)\nInstalling collected packages: datafusion\nSuccessfully installed datafusion-25.0.0\n"]}],"execution_count":1,"metadata":{"id":"zp9radlkeSGP"}},{"cell_type":"code","source":["sf =30"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":4,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:20:55.2911316Z","session_start_time":null,"execution_start_time":"2023-06-15T05:21:19.8821176Z","execution_finish_time":"2023-06-15T05:21:20.2396856Z","spark_jobs":{"numbers":{"SUCCEEDED":0,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"5fd853a5-ce15-4230-b589-35995e816faf"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 4, Finished, Available)"},"metadata":{}}],"execution_count":2,"metadata":{"jupyter":{"source_hidden":false,"outputs_hidden":false},"nteract":{"transient":{"deleting":false}}}},{"cell_type":"code","source":["%%time\r\n","\r\n","import duckdb\r\n","import pathlib\r\n","import os\r\n","\r\n","if not os.path.isdir(f'/lakehouse/default/Files/{sf}'):\r\n"," for x in range(0, sf) :\r\n"," con=duckdb.connect()\r\n"," con.sql('PRAGMA disable_progress_bar;SET preserve_insertion_order=false')\r\n"," con.sql(f\"CALL dbgen(sf={sf} , children ={sf}, step = {x})\") \r\n"," for tbl in ['lineitem'] :\r\n"," pathlib.Path(f'/lakehouse/default/Files/{sf}/{tbl}').mkdir(parents=True, exist_ok=True) \r\n"," con.sql(f\"COPY (SELECT * FROM {tbl}) TO '/lakehouse/default/Files/{sf}/{tbl}/{x:03d}.parquet' \")\r\n"," con.close()"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":5,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:20:55.2917013Z","session_start_time":null,"execution_start_time":"2023-06-15T05:21:20.8377541Z","execution_finish_time":"2023-06-15T05:21:21.8709022Z","spark_jobs":{"numbers":{"SUCCEEDED":0,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"93c91743-a8dd-4fcc-8207-8f5508124c78"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 5, Finished, Available)"},"metadata":{}},{"output_type":"stream","name":"stdout","text":["CPU times: user 49.7 ms, sys: 12.9 ms, total: 62.6 ms\nWall time: 561 ms\n"]}],"execution_count":3,"metadata":{"jupyter":{"source_hidden":false,"outputs_hidden":false},"nteract":{"transient":{"deleting":false}}}},{"cell_type":"code","source":["from psutil import *\n","vCPU = str(cpu_count()) + \" vCPU\"\n","mem=round(virtual_memory().total/(1024 * 1024 * 1024),0)\n","runtime = 'Sorting Lineitem-SF'+str(sf)+' ,Fabric Notebook, '+vCPU+' '+str(mem)+'GB'\n","runtime"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":6,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:20:55.2924784Z","session_start_time":null,"execution_start_time":"2023-06-15T05:21:22.4699737Z","execution_finish_time":"2023-06-15T05:21:22.8136074Z","spark_jobs":{"numbers":{"SUCCEEDED":0,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"adfa2421-2fc9-4a1a-aaa1-1179518c6a45"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 6, Finished, Available)"},"metadata":{}},{"output_type":"execute_result","execution_count":17,"data":{"text/plain":"'Sorting Lineitem-SF30 ,Fabric Notebook, 8 vCPU 63.0GB'"},"metadata":{}}],"execution_count":4,"metadata":{"colab":{"base_uri":"https://localhost:8080/","height":35},"id":"XZag4ZSSXUqw","outputId":"616a912d-a277-482b-ecb1-17e2a6f85a7a"}},{"cell_type":"code","source":["import os\r\n","mypath = f\"/lakehouse/default/Files/{sf}/Sort/\"\r\n","os.makedirs(mypath, exist_ok=True)\r\n","for root, dirs, files in os.walk(mypath, topdown=False):\r\n"," for file in files:\r\n"," os.remove(os.path.join(root, file))\r\n","\r\n"," # Add this block to remove folders\r\n"," for dir in dirs:\r\n"," os.rmdir(os.path.join(root, dir))"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":7,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:20:55.2939212Z","session_start_time":null,"execution_start_time":"2023-06-15T05:21:23.3538574Z","execution_finish_time":"2023-06-15T05:21:26.0471349Z","spark_jobs":{"numbers":{"SUCCEEDED":0,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"961f3844-255d-49b4-97a7-ef92c4014b99"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 7, Finished, Available)"},"metadata":{}}],"execution_count":5,"metadata":{"jupyter":{"source_hidden":false,"outputs_hidden":false},"nteract":{"transient":{"deleting":false}}}},{"cell_type":"markdown","source":["# DuckDB"],"metadata":{"id":"yqhDecjmncVE"}},{"cell_type":"code","source":["%%time\n","import time\n","start = time.time()\n","import duckdb\n","con=duckdb.connect()\n","con.sql(\n","f'''\n","PRAGMA disable_progress_bar;\n","COPY (select * from '/lakehouse/default/Files/{sf}/lineitem/*.parquet' order by l_shipdate )\n","to '/lakehouse/default/Files/{sf}/Sort/lineitem_DuckDB_Sort' (FORMAT 'PARQUET', PER_THREAD_OUTPUT TRUE)\n","''')\n","con.close()\n","duckdb_duration = time.time()-start"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":8,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:20:55.2944094Z","session_start_time":null,"execution_start_time":"2023-06-15T05:21:26.4262659Z","execution_finish_time":"2023-06-15T05:23:18.9697127Z","spark_jobs":{"numbers":{"SUCCEEDED":0,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"e62bb512-93e9-41d5-a375-2c448befec58"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 8, Finished, Available)"},"metadata":{}},{"output_type":"stream","name":"stdout","text":["CPU times: user 7min 57s, sys: 1min 24s, total: 9min 22s\nWall time: 1min 50s\n"]}],"execution_count":6,"metadata":{"id":"0HK-TCztkYmr","colab":{"base_uri":"https://localhost:8080/"},"outputId":"578af9b5-cd83-4d4a-e1d9-f119fc37712d"}},{"cell_type":"markdown","source":["# DataFusion"],"metadata":{"id":"HeDmyVhzee8V"}},{"cell_type":"code","source":["%%time\n","start = time.time()\n","from datafusion import SessionContext\n","ctx = SessionContext()\n","ctx.register_parquet('lineitem', f'/lakehouse/default/Files/{sf}/lineitem/*.parquet')\n","df = ctx.sql(\"select * from lineitem order by l_shipdate\")\n","df.write_parquet(f\"/lakehouse/default/Files/{sf}/Sort/lineitem_Datafusion_Sort\")\n","Datafusion_duration = time.time()-start"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":9,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:20:55.2953011Z","session_start_time":null,"execution_start_time":"2023-06-15T05:23:19.4453466Z","execution_finish_time":"2023-06-15T05:26:29.654669Z","spark_jobs":{"numbers":{"SUCCEEDED":0,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"4f500cf6-3f57-4435-af1e-cbf84ac9460c"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 9, Finished, Available)"},"metadata":{}},{"output_type":"stream","name":"stdout","text":["CPU times: user 6min 30s, sys: 46.5 s, total: 7min 16s\nWall time: 3min 9s\n"]}],"execution_count":7,"metadata":{"id":"jq0cwqC50y1f","colab":{"base_uri":"https://localhost:8080/"},"outputId":"f341b8c7-cf70-417a-e111-229825242bc1"}},{"cell_type":"markdown","source":["# Spark"],"metadata":{"id":"N7ecHVITNr4F"}},{"cell_type":"code","source":["%%time\n","import time\n","start = time.time()\n","df = spark.read.parquet(f\"Files/{sf}/lineitem/*.parquet\")\n","df.orderBy(\"l_shipdate\")\n","df.write.mode(\"overwrite\").format(\"parquet\").save(f\"Files/{sf}/Sort/Lineitem_Spark_Sort\")\n","Spark_duration = time.time()-start"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":10,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:20:55.2959693Z","session_start_time":null,"execution_start_time":"2023-06-15T05:26:31.3290117Z","execution_finish_time":"2023-06-15T05:28:40.7915143Z","spark_jobs":{"numbers":{"SUCCEEDED":2,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[{"dataWritten":6534117560,"dataRead":8140998749,"rowCount":359996744,"jobId":8,"name":"save at NativeMethodAccessorImpl.java:0","description":"Job group for statement 10:\n%%time\nimport time\nstart = time.time()\ndf = spark.read.parquet(f\"Files/{sf}/lineitem/*.parquet\")\ndf.orderBy(\"l_shipdate\")\ndf.write.mode(\"overwrite\").format(\"parquet\").save(f\"Files/{sf}/Sort/Lineitem_Spark_Sort\")\nSpark_duration = time.time()-start","submissionTime":"2023-06-15T05:26:35.542GMT","completionTime":"2023-06-15T05:28:38.600GMT","stageIds":[11],"jobGroup":"10","status":"SUCCEEDED","numTasks":62,"numActiveTasks":0,"numCompletedTasks":62,"numSkippedTasks":0,"numFailedTasks":0,"numKilledTasks":0,"numCompletedIndices":62,"numActiveStages":0,"numCompletedStages":1,"numSkippedStages":0,"numFailedStages":0,"killedTasksSummary":{}},{"dataWritten":0,"dataRead":0,"rowCount":0,"jobId":7,"name":"parquet at NativeMethodAccessorImpl.java:0","description":"Job group for statement 10:\n%%time\nimport time\nstart = time.time()\ndf = spark.read.parquet(f\"Files/{sf}/lineitem/*.parquet\")\ndf.orderBy(\"l_shipdate\")\ndf.write.mode(\"overwrite\").format(\"parquet\").save(f\"Files/{sf}/Sort/Lineitem_Spark_Sort\")\nSpark_duration = time.time()-start","submissionTime":"2023-06-15T05:26:34.483GMT","completionTime":"2023-06-15T05:26:35.302GMT","stageIds":[10],"jobGroup":"10","status":"SUCCEEDED","numTasks":1,"numActiveTasks":0,"numCompletedTasks":1,"numSkippedTasks":0,"numFailedTasks":0,"numKilledTasks":0,"numCompletedIndices":1,"numActiveStages":0,"numCompletedStages":1,"numSkippedStages":0,"numFailedStages":0,"killedTasksSummary":{}}],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"a2c9c582-b86d-4997-a3a0-7f132604cb82"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 10, Finished, Available)"},"metadata":{}},{"output_type":"stream","name":"stdout","text":["CPU times: user 21.9 ms, sys: 5.92 ms, total: 27.8 ms\nWall time: 2min 7s\n"]}],"execution_count":8,"metadata":{"id":"DsXvjuwRN0U2"}},{"cell_type":"markdown","source":["# Polars"],"metadata":{"id":"-odTmS2dikyT"}},{"cell_type":"code","source":["%%time\n","#start = time.time()\n","#import polars as pl\n","#pl.scan_parquet(f\"/lakehouse/default/Files/{sf}/lineitem/*.parquet\")\\\n","#.sort(\"l_shipdate\").sink_parquet(f\"/lakehouse/default/Files/{sf}/Sort/lineitem_sort_polars.parquet\")\n","#polars_duration = time.time()-start"],"outputs":[],"execution_count":null,"metadata":{"id":"GlEMX0jOcJ4M","colab":{"base_uri":"https://localhost:8080/"},"outputId":"414c0f84-6551-40ea-8e50-cc676b0784f5"}},{"cell_type":"markdown","source":["# Result"],"metadata":{"nteract":{"transient":{"deleting":false}}}},{"cell_type":"code","source":["import pandas as pd\r\n","#df = pd.DataFrame([{'DuckDB':duckdb_duration, 'Spark':Spark_duration , 'Datafusion':Datafusion_duration , 'Polars':polars_duration }])\r\n","df = pd.DataFrame([{'DuckDB':duckdb_duration, 'Spark':Spark_duration , 'Datafusion':Datafusion_duration }])\r\n","ax = df.plot.bar(rot=0,title=runtime,ylabel='Duration in Second, Lower is Better',figsize=(18,5))"],"outputs":[{"output_type":"display_data","data":{"application/vnd.livy.statement-meta+json":{"spark_pool":null,"session_id":"4f7b9513-9c96-4853-b0bc-05666154b9da","statement_id":15,"state":"finished","livy_statement_state":"available","queued_time":"2023-06-15T05:34:55.5814589Z","session_start_time":null,"execution_start_time":"2023-06-15T05:34:56.0513065Z","execution_finish_time":"2023-06-15T05:34:57.1407026Z","spark_jobs":{"numbers":{"SUCCEEDED":0,"UNKNOWN":0,"RUNNING":0,"FAILED":0},"jobs":[],"limit":20,"rule":"ALL_DESC"},"parent_msg_id":"cf3a9d56-1e17-4542-bbc4-15f2ad94045f"},"text/plain":"StatementMeta(, 4f7b9513-9c96-4853-b0bc-05666154b9da, 15, Finished, Available)"},"metadata":{}},{"output_type":"display_data","data":{"text/plain":"","image/png":"iVBORw0KGgoAAAANSUhEUgAABb4AAAHBCAYAAACmIK1/AAAAOXRFWHRTb2Z0d2FyZQBNYXRwbG90bGliIHZlcnNpb24zLjYuMywgaHR0cHM6Ly9tYXRwbG90bGliLm9yZy/P9b71AAAACXBIWXMAAA9hAAAPYQGoP6dpAABom0lEQVR4nO3deVxUZf//8ffIJrsiIqAIaJkb7qVhJWguqLi2mJaiZouVmppLfr3VLDFbtCzrbhNNUyu3cs3cTSuXNFzuMsMdwg0QUkQ4vz/6MbcjoDM4iM79ej4e8/hyrnOdc94zzEz39+PF55gMwzAEAAAAAAAAAICDKFPaAQAAAAAAAAAAsCcK3wAAAAAAAAAAh0LhGwAAAAAAAADgUCh8AwAAAAAAAAAcCoVvAAAAAAAAAIBDofANAAAAAAAAAHAoFL4BAAAAAAAAAA6FwjcAAAAAAAAAwKFQ+AYAAAAAAAAAOBQK3wAA4Ib89NNP6tq1q6pWrSo3NzdVqlRJ9957r4YNG2b3a82YMUMJCQkFxg8fPiyTyVTovpKWf+0333zzmvPCwsIUFxdXolkSEhJkMpl0+PBh89gXX3yhadOmleh1b4S175+oqCiZTKZCH3v37pUkHTt2TF27dlW1atXk6ekpX19fNWzYUO+9954uX75c4Np//vmnunXrpnLlysnLy0utW7fWrl27iv1c8l//wh7Dhw+3+jwbNmyQyWTS119/XewskhQXF6ewsLAbOke+8ePHy2QyKSAgQOfPny+wPywsTB07dizWuSdNmqQlS5YUO5u1n8GSYK/f1ZUMw9DHH3+sxo0by8fHRxUqVFCLFi20fPlyu10jX0ZGhl577TU1adJEPj4+cnNzU1hYmPr162fxWbj6ve3s7KwqVaqob9++OnHiRIF5O3bsKPR6HTt2tPo9mZOTo7ffflsRERFyd3dXuXLlFBkZqa1bt5rnZGVlqUePHrrrrrvk7e0tT09P1alTR6+++qqysrKsvs6ECRMUFhYmNzc31axZU9OnTy9y/rJly9S5c2cFBwfL1dVV3t7eatiwocaNG6ejR49azL36e8vFxUVhYWHq37+/jhw5YlU+AABQfM6lHQAAANy+li9frk6dOikqKkpTpkxRUFCQkpOTtWPHDs2fP19vvfWWXa83Y8YM+fv7FyggBwUFadu2bapevbpdr2dPixcvlo+PT4leo0OHDtq2bZuCgoLMY1988YX27t2rIUOGlOi1i8PW90+1atU0d+7cAufJ/71nZWXJx8dHY8eOVdWqVXXp0iWtWLFCL7zwgnbv3q1PPvnEfMypU6d0//33q3z58vrss89UtmxZxcfHKyoqStu3b9ddd91V7Oc1c+ZM1axZ02IsODi42OcrrrFjx2rw4MF2PeepU6c0ZcoUTZw40W7nnDRpkh566CF16dLFbue8nY0bN04TJ07UM888o8mTJ+vixYuaPn26OnbsqIULF6pbt252uc6hQ4fUpk0bpaam6plnntGECRPk5eWlw4cP68svv1Tjxo2VlpYmX19f8zH57+0LFy5o06ZNio+P18aNG5WYmChPT0+75JKk3Nxcde3aVVu2bNGIESMUGRmprKws7dy506KgnZOTI8MwNHToUIWHh6tMmTLatGmTXnnlFW3YsEHff//9da81cOBAff7555o4caLuvvturV69WoMHD9b58+f18ssvm+fl5eWpb9++mj17tmJiYhQfH6+wsDBduHBB27dv18yZM/XZZ5/p2LFjFue/8nvr0qVL2rt3ryZMmKA1a9boP//5jzw8POz0qgEAgAIMAACAYnrggQeM6tWrGzk5OQX25ebm2u06WVlZhmEYRp06dYwWLVrY7bz2kJSUZEgy3njjjdKOUqgOHToYoaGhpR2jULa8f1q0aGHUqVOnWNd55JFHDGdnZ+PixYvmsZdeeslwcXExDh8+bB5LT083/P39jUceeaRY15k5c6Yhydi+fXuxjs+3fv16Q5Lx1VdfFev4/M+LPY0bN86QZLRr187w9PQ0kpOTLfaHhoYaHTp0KNa5PT09jT59+hQ7W2l+Bm/0d1WYypUrG/fdd5/F2IULFwxfX1+jU6dOdrnG5cuXjYiICMPHx8dITEwsdM6KFSvM76Wi3ttjx441JBlz5sy55rx81n4fTZ061ShTpoyxbds2G57Vf40YMcKQZBw6dOia8/bu3WuYTCZj0qRJFuMDBgww3N3djTNnzpjHJk2aZEgy4uPjCz1XTk6O8d5771mMFfW99emnnxqSjNWrV1v7lAAAQDHQ6gQAABTbmTNn5O/vL2fngn9EVqaM5f/MyMvL05QpU1SzZk25ubkpICBAvXv31vHjxy3mRUVFqW7dutq0aZMiIyPl4eGhfv36KSwsTPv27dPGjRvNfzae/yfzhbU6yW/NsG/fPj322GPy9fVVpUqV1K9fP6Wnp1tcMy0tTf3795efn5+8vLzUoUMH/fnnnzKZTBo/frxdXqurW53kt0iYN2+exowZo+DgYPn4+OjBBx/Ub7/9VuD477//Xq1atZKPj488PDzUvHlzrV271mLO1a1OoqKitHz5ch05csTiz+3zXbp0Sa+++qr5d1KxYkX17dtXp06dKpC9Y8eOWrZsmRo2bCh3d3fVqlVLy5YtM1+3Vq1a8vT01D333FNkm4Or2fL+uREVK1ZUmTJl5OTkZB5bvHixWrZsqdDQUPOYj4+PunXrpm+//bbQ1ig36o8//lDfvn115513ysPDQ5UrV1ZsbKwSExMLnX/x4kUNHTpUgYGBcnd3V4sWLfTLL79YzImLi5OXl5cSExPVpk0beXt7q1WrVuZ9V7eVyMvL0/Tp09WgQQNz+4hmzZrpm2++seo5vPrqq7p8+bJVn4uzZ89q4MCBqly5slxdXVWtWjWNGTNG2dnZ5jkmk0lZWVmaNWuW+f0ZFRVl3p+SkqKnn35aVapUkaurq8LDwzVhwoRCfz95eXl67bXXVLVqVZUtW1ZNmjQp8BmRpC1btqhVq1by9vaWh4eHIiMjC20jsnfvXnXu3Fnly5dX2bJl1aBBA82aNeu6zzsjI0Nt27ZVpUqV9PPPP193/tVcXFwsVllLUtmyZc2Pa2nYsKHuv//+AuO5ubmqXLmyebX4kiVLlJiYqNGjR6tu3bqFnismJua6q5GbNWsmSXZv2/HOO+/ogQceMJ/fVhUrVpSkQr9brrRkyRIZhqG+fftajPft21cXLlzQqlWrJP3zXTllyhTVrVtXo0aNKvRczs7Oeu6556zKl//7dXFxsWo+AAAoHgrfAACg2O6991799NNPGjRokH766Sfl5OQUOffZZ5/VyJEj1bp1a33zzTeaOHGiVq1apcjISJ0+fdpibnJysh5//HH17NlTK1as0MCBA7V48WJVq1ZNDRs21LZt27Rt2zYtXrz4uhm7d++uGjVqaOHChRo1apS++OILvfjii+b9eXl5io2N1RdffKGRI0dq8eLFatq0qdq1a1f8F8YGL7/8so4cOaJPPvlEH330kQ4ePKjY2Fjl5uaa58yZM0dt2rSRj4+PZs2apS+//FJ+fn5q27ZtoYW9fDNmzFDz5s0VGBhofs22bdsm6Z/n3blzZ02ePFk9e/bU8uXLNXnyZK1Zs0ZRUVG6cOGCxbn27Nmj0aNHa+TIkVq0aJF8fX3VrVs3jRs3Tp988okmTZqkuXPnKj09XR07dixwfGFsef/ku3z5ssUjLy+vwBzDMHT58mWdO3dOCxYsUEJCgoYNG2Yugl24cEGHDh1SvXr1Chxbr149XbhwQX/++ed1sxQlNze3QE5JOnnypCpUqKDJkydr1apVev/99+Xs7KymTZsW+o8dL7/8sv7880998skn+uSTT3Ty5ElFRUUVyHbp0iV16tRJLVu21NKlSzVhwoQis8XFxWnw4MG6++67tWDBAs2fP1+dOnWy6At/LaGhoRo4cKA+/fRT/f7770XOu3jxoqKjozV79mwNHTpUy5cv1+OPP64pU6ZYtOrYtm2b3N3d1b59e/P7c8aMGZL+KXrfc889Wr16tf71r39p5cqV6t+/v+Lj4zVgwIAC13zvvfe0atUqTZs2TXPmzFGZMmUUExNjfs9L0saNG9WyZUulp6fr008/1bx58+Tt7a3Y2FgtWLDAPO+3335TZGSk9u3bp3fffVeLFi1S7dq1FRcXpylTphT5vI8fP6777rtPR44c0bZt23TPPfdY9bpeafDgwVq1apU+/fRTnTt3TsnJyRo6dKjS09M1aNCgax7bt29fbdmyRQcPHrQY/+6773Ty5Elzgfe7776TpBtuL/PHH39I+m+h2R6OHTumw4cPKyIiQi+//LIqVaokZ2dn1alTp8h/eMj/zGdkZGjVqlV666239Nhjj6lq1arXvNbevXtVsWJFBQYGWoznfzfk3z9gx44dSktLU2xsbLGeU/73wN9//62ff/5Zr7zyiqpVq6bIyMhinQ8AAFiplFecAwCA29jp06eN++67z5BkSDJcXFyMyMhIIz4+3jh//rx53oEDBwxJxsCBAy2O/+mnnwxJxssvv2wea9GihSHJWLt2bYHrFdXqJL/VwcyZM81j+a0ZpkyZYjF34MCBRtmyZY28vDzDMAxj+fLlhiTjgw8+sJgXHx9vSDLGjRt3zdfA2jYLoaGhFu0c8lsktG/f3mLel19+aUgy/4l/VlaW4efnZ8TGxlrMy83NNerXr2/cc8895rH8NgNJSUnmsaJaC8ybN8+QZCxcuNBifPv27YYkY8aMGRbZ3d3djePHj5vHdu/ebUgygoKCLFprLFmyxJBkfPPNN9d8PQzD+vePYfz3fXH1o1evXgXOm/+7k2SYTCZjzJgxFvtPnDhRZMuCL774wpBkbN269br5r5b/+hf2KKydy+XLl41Lly4Zd955p/Hiiy+ax/PfG40aNTK/Tw3DMA4fPmy4uLgYTz75pHmsT58+hiTjs88+K3D+Pn36WPzuN23aZEgq8HpYI//zdOrUKeP06dOGr6+v0b17d/P+q1udfPjhh4Yk48svv7Q4z+uvv25IMr777jvzWFGtTp5++mnDy8vLOHLkiMX4m2++aUgy9u3bZxjGfz+DwcHBxoULF8zzMjIyDD8/P+PBBx80jzVr1swICAiweH9dvnzZqFu3rlGlShXz692jRw/Dzc3NOHr0qMW1Y2JiDA8PDyMtLc0wDMtWJ7/88osRHBxs3H///RYtMorjww8/NNzc3MzvHz8/P2PNmjXXPe706dOGq6urxXeqYfzT7qdSpUrm92G7du0MSRbtf64l/739448/Gjk5Ocb58+eNZcuWGRUrVjS8vb2NlJQUi3k30upk27ZthiTDx8fHqF27tvHll18aq1evNh566CFDkvHRRx8VOCb/+yz/0bdv30I/c1dr3bq1cddddxW6z9XV1XjqqacMwzCM+fPnG5KMDz/8sMC8nJwci8eVivreqlGjhnHgwIHr5gMAADeGFd8AAKDYKlSooM2bN2v79u2aPHmyOnfurN9//12jR49WRESEeSX3+vXrJanATSnvuece1apVq8Cq5fLly6tly5Z2ydipUyeL7Xr16unixYtKTU2V9M8KUEl65JFHLOY99thjdrl+cfJJ/20dsHXrVp09e1Z9+vQpsNK5Xbt22r59u8XN3qy1bNkylStXTrGxsRbnbdCggQIDA7VhwwaL+Q0aNFDlypXN27Vq1ZL0TzuVK9sh5I/n5zf+/0rMq1c/S9a/f/JVr15d27dvt3gUdpPFuLg4bd++XatXr9aIESP0xhtv6IUXXigw78q2L7bsu57Zs2cXyOns7KzLly9r0qRJql27tlxdXeXs7CxXV1cdPHhQBw4cKHCenj17WuQIDQ1VZGSk+fN0pe7du18318qVKyXJ6nYMRalQoYJGjhyphQsX6qeffip0zrp16+Tp6amHHnrIYjz/O+Baf6mQb9myZYqOjlZwcLDF+ycmJkbSfz+7+bp162bRCiR/JfemTZuUm5urrKws/fTTT3rooYfk5eVlnufk5KQnnnhCx48fN6+8X7dunVq1aqWQkJAC+f/++2+LVeSStHr1at1///164IEHtGbNGvn5+V33+RVl5syZGjx4sJ5//nl9//33WrFihdq0aaPOnTtr9erV1zy2QoUKio2N1axZs8x/DXHu3DktXbpUvXv3vm7rj+tp1qyZXFxc5O3trY4dOyowMFArV65UpUqVbui8V8rPffHiRa1YsUIPP/yw2rRpoy+//FKNGjXSK6+8UuCYtm3bavv27Vq3bp1ee+01LVy4UN27dy/0L0KudiPfA2lpaXJxcbF4XN3q6crvrW3btumLL76Qu7u7WrVqVWBlPgAAsK8b+18+AAAAkpo0aaImTZpIknJycjRy5EhNnTpVU6ZM0ZQpU3TmzBlJUlBQUIFjg4ODC/SHLWxecVWoUMFi283NTZLMrTjOnDkjZ2fnAoUqexZybiTfX3/9JUkFCohXOnv2rDw9PW267l9//aW0tDS5uroWuv/qovPVr0/+cUWNX7x4UdI/xcno6GiLOUlJSRa9p6/3/smX37f5egIDA82tC9q0aaPy5ctr1KhR6tevnxo2bKjy5cvLZDKZ35dXOnv2bKHPyxa1atUqNOfQoUP1/vvva+TIkWrRooXKly+vMmXK6Mknnyy0NczV7Rfyx/bs2WMx5uHhIR8fn+vmOnXqlJycnAo9r62GDBmi9957TyNGjChQgJb++VwFBgYWKBwGBATI2dm50Nf+an/99Ze+/fbbIvsgX/0eLer1unTpkjIzM3X+/HkZhlHk91B+7vz/a828fEuWLNGFCxf07LPPmj/DxXHu3Dk999xzevLJJ/Xmm2+ax2NiYhQVFaVnnnlGSUlJ1zxHv379tHDhQq1Zs0Zt27bVvHnzlJ2dbfEPj/ktQJKSklSzZk2r882ePVu1atWSs7OzKlWqVOA1yi+sX9mq6UqXL1++bl/r/O/EmjVrWvTgN5lMatu2reLj45WamqqAgADzvvLly5s/c9HR0apevbp69OihpUuXqmvXrte81u7duwuMZ2Vl6dKlS+bvgfzX6+r/Vnl7e2v79u2S/vmHmsLaDF39vdWsWTNFRUWpcuXK+te//qV58+Zd8/UAAADFR+EbAADYlYuLi8aNG6epU6ea+6PmFzKSk5NVpUoVi/knT56Uv7+/xdiNrLa1VYUKFXT58mWdPXvWotiZkpJy0zJcS/5rM3369CJv9FacIr2/v78qVKhgvnnb1by9vW0+Z2EaN25sLgzlyy8eFqaw98+Nyu+z/Pvvv5tvznnHHXcUelPJxMREubu7q1q1ana59pXmzJmj3r17a9KkSRbjp0+fVrly5QrML+w9mJKSUuAfS6z9vFSsWFG5ublKSUm54X9ccnd31/jx4/XUU08VemPIChUq6KeffpJhGBb5UlNTdfny5QKf+cL4+/urXr16eu211wrdf/X7qKjXy9XVVV5eXnJ2dlaZMmWUnJxcYN7JkyfN18zPb828fFOnTtWCBQsUExOjxYsXq02bNtd9foX57bffdOHCBd19990F9jVp0kQbN25UZmamxYr1q7Vt21bBwcGaOXOm2rZtq5kzZ6pp06aqXbu2xZyPPvpIS5YsKfJmjYUp6h918uV/F504caLQ/SdOnLju91X16tWLvKmmYRiSrn/z2ys/89cSERGh+fPnKyUlxeIfTvK/G/Jv/Nm4cWOVL19e3377rcXn18nJyfx62PJ9FRQUJH9//wL/iAUAAOyLVicAAKDYCisMSTK3bcgvTOW3LZkzZ47FvO3bt+vAgQNq1aqVVddzc3Oz6qaJtmjRooUkWdzYTpLmz59v1+sUV/PmzVWuXDnt37/fvDL66kdRq7alol+zjh076syZM8rNzS30nHfddZdd8nt7exeZ19r3z43Kbw1yxx13mMe6du2qdevW6dixY+ax8+fPa9GiRerUqdMNt4QojMlkKrAaePny5UUWCefNm2cu9En/rDbdunWroqKiinX9/BYhH3zwQbGOv1q/fv1Uq1YtjRo1qkBLiVatWikzM1NLliyxGJ89e7Z5f75rvUf37t2r6tWrF/oevfr9sWjRIvNfGkj//D6//fZb3X///XJycpKnp6eaNm2qRYsWWVwvLy9Pc+bMUZUqVVSjRg1zvnXr1pkL3Vfm9/DwKPCPUGXLltWiRYvUsWNHderUSUuXLr3ey1eo/Of0448/WowbhqEff/xR5cuXv+5fd+S3blmyZIk2b96sHTt2qF+/fhZzOnfurIiICMXHxxdZsF29erX+/vtvm/I3a9ZMXl5eBb5PJWn//v3at2+fHnzwwWuew9nZWZ07d9aBAwcsbrpqGIZWrVql6tWrX/cfTgr7zBemc+fOMplMBW6amZCQIHd3d/NNjl1dXfXSSy9p7969ev311695TmscP35cp0+ftli1DgAA7I8V3wAAoNjatm2rKlWqKDY2VjVr1lReXp52796tt956S15eXho8eLAk6a677tJTTz2l6dOnq0yZMoqJidHhw4c1duxYhYSE6MUXX7Tqevmr8xYsWKBq1aqpbNmyioiIuKHn0K5dOzVv3lzDhg1TRkaGGjdurG3btpkLdNdbWZgvMTFRX3/9dYHxu+++2+LP9W3l5eWl6dOnq0+fPjp79qweeughBQQE6NSpU9qzZ49OnTp1zUJmRESEFi1apA8++ECNGzdWmTJl1KRJE/Xo0UNz585V+/btNXjwYN1zzz1ycXHR8ePHtX79enXu3PmaLQLswdr3j7XGjRunv/76Sw888IAqV66stLQ0rVq1Sh9//LEefvhhNW7c2Dx3+PDh+vzzz9WhQwe98sorcnNz0+TJk3Xx4kWNHz/+utdKSEhQ3759NXPmzAK964vSsWNHJSQkqGbNmqpXr5527typN954o8BfQeRLTU1V165dNWDAAKWnp2vcuHEqW7asRo8ebdX1rnb//ffriSee0Kuvvqq//vpLHTt2lJubm3755Rd5eHgU2gf9WpycnDRp0iTz+yS/P70k9e7dW++//7769Omjw4cPKyIiQlu2bNGkSZPUvn17i+JnRESENmzYoG+//VZBQUHy9vbWXXfdpVdeeUVr1qxRZGSkBg0apLvuuksXL17U4cOHtWLFCn344YcWr52Tk5Nat26toUOHKi8vT6+//royMjIs2k/Ex8erdevWio6O1vDhw+Xq6qoZM2Zo7969mjdvnnl1+rhx48w9xv/1r3/Jz89Pc+fO1fLlyzVlyhT5+voWeD1cXFw0b948Pfnkk3rooYc0e/Zsi3sFmEwmtWjRokD//CtVrVpV3bp100cffSQ3Nze1b99e2dnZmjVrln744QdNnDjRqhX+/fr10+uvv66ePXvK3d1djz76aIHfXf7K9HvvvVfPPvusoqOj5enpqSNHjujrr7/Wt99+q3Pnzl33Wlfy9vbWhAkTNGzYMOXl5enRRx9V+fLllZiYqEmTJik0NFSDBg267nkmTpyolStXql27dho/frx8fHz0ySefaM+ePfryyy/N8/79739r8+bNatOmjUJCQpSVlaXNmzdr+vTpioyMVOfOnc1zZ8+erX79+umzzz5T7969JUl16tRR//79NW7cODk5Oenuu+/Wd999p48++kivvvqqxV8BjRw5Uv/5z380atQobdq0SY8++qjCwsKUnZ2tP//8U5988omcnJwKrFa/cOGC+R8ycnNzlZSUZG7hNGTIEJteXwAAYKNSvLEmAAC4zS1YsMDo2bOnceeddxpeXl6Gi4uLUbVqVeOJJ54w9u/fbzE3NzfXeP31140aNWoYLi4uhr+/v/H4448bx44ds5jXokULo06dOoVe7/Dhw0abNm0Mb29vQ5IRGhpqGIZhJCUlGZKMmTNnmueOGzfOkGScOnXK4hwzZ840JBlJSUnmsbNnzxp9+/Y1ypUrZ3h4eBitW7c2fvzxR0OS8c4771zzNci/dlGP/EyhoaFGnz59zMetX7/ekGR89dVXhZ7vyudiGIaxceNGo0OHDoafn5/h4uJiVK5c2ejQoYPF8UU9t4ceesgoV66cYTKZjCv/519OTo7x5ptvGvXr1zfKli1reHl5GTVr1jSefvpp4+DBg+Z5oaGhRocOHQo8d0nGc889V2j+N95445qvm2HY9v651vsi3zfffGM8+OCDRqVKlQxnZ2fDy8vLuOeee4x3333XyMnJKTD/jz/+MLp06WL4+PgYHh4eRqtWrYydO3deN7dhGMb06dMNScaqVavMY/mv//bt2ws95ty5c0b//v2NgIAAw8PDw7jvvvuMzZs3Gy1atDBatGhhnpf/3vj888+NQYMGGRUrVjTc3NyM+++/39ixY4fFOfv06WN4enoWer0+ffqYPyP5cnNzjalTpxp169Y1XF1dDV9fX+Pee+81vv3222s+36I+T4ZhGJGRkYakAu+RM2fOGM8884wRFBRkODs7G6Ghocbo0aONixcvWszbvXu30bx5c8PDw8OQZPFanDp1yhg0aJARHh5uuLi4GH5+fkbjxo2NMWPGGJmZmYZh/Pc99/rrrxsTJkwwqlSpYri6uhoNGzY0Vq9eXSDv5s2bjZYtWxqenp6Gu7u70axZs0Kff2JiohEbG2v4+voarq6uRv369Qt8Lgv7HOfl5RmDBg0yypQpY3z88ceGYRjG+fPnDUlGjx49rvk6G4ZhXLhwwXjjjTeMevXqGd7e3oafn5/RrFkzY86cOUZeXt51j8+X/3vp1atXkXPS0tKMiRMnGo0aNbL4DD7++OPGDz/8YJ53vff21b788kvjvvvuM7y9vQ1nZ2ejatWqxrPPPmukpKRYnT8xMdHo0KGD4e3tbZQtW7bQ39MPP/xgdOzY0QgODjZcXV0NDw8Po379+sbEiRONrKwsi7n5z+Hq3+GlS5eMcePGGVWrVjVcXV2NGjVqGO+++26Rub755hsjNjbW/D3j7e1tNGjQwBg2bJjxn//8x2JuixYtLP57UKZMGSM4ONiIiYkxNmzYYPVrAQAAisdkGFf8/SQAAAAkSV988YV69eqlH374QZGRkaUdB7eYRx55RElJSQX6lwOFWbFihTp27Kg9e/bc8F+pAAAAwDq0OgEAAP/z5s2bpxMnTigiIkJlypTRjz/+qDfeeEMPPPAARW8UYBiGNmzYUKBnPVCU9evXq0ePHhS9AQAAbiJWfAMAgP95y5Yt0/jx4/XHH38oKytLQUFB6tKli1599VX5+PiUdjwAAAAAgI0ofAMAAAAAAAAAHEqZ0g4AAAAAAAAAAIA9UfgGAAAAAAAAADgUCt8AAAAAAAAAAIfiXNoBbgV5eXk6efKkvL29ZTKZSjsOAAAAAAAAAKAQhmHo/PnzCg4OVpkyRa/rpvAt6eTJkwoJCSntGAAAAAAAAAAAKxw7dkxVqlQpcj+Fb0ne3t6S/nmxfHx8SjkNAAAAAAAAAKAwGRkZCgkJMdd0i0LhWzK3N/Hx8aHwDQAAAAAAAAC3uOu1rObmlgAAAAAAAAAAh0LhGwAAAAAAAADgUCh8AwAAAAAAAAAcCj2+AQAAAAAAANzycnNzlZOTU9oxUMJcXFzk5OR0w+eh8A0AAAAAAADglmUYhlJSUpSWllbaUXCTlCtXToGBgde9geW1UPgGAAAAAAAAcMvKL3oHBATIw8PjhoqhuLUZhqG///5bqampkqSgoKBin4vCNwAAAAAAAIBbUm5urrnoXaFChdKOg5vA3d1dkpSamqqAgIBitz3h5pYAAAAAAAAAbkn5Pb09PDxKOQlupvzf9430dKfwDQAAAAAAAOCWRnuT/y32+H1T+AYAAAAAAAAAOBQK3wAAAAAAAABwm4qLi1OXLl1KO8Yth5tbAgAAAAAAALjthI1aflOvd3hyB5vmx8XFadasWZIkZ2dn+fn5qV69enrssccUFxenMmVuzprkhIQE9e3bV5JUpkwZ+fj4qEaNGurQoYMGDx4sX1/fQjNLkp+fn+6++25NmTJF9erVuyl57YUV3wAAAAAAAABQAtq1a6fk5GQdPnxYK1euVHR0tAYPHqyOHTvq8uXLNy2Hj4+PkpOTdfz4cW3dulVPPfWUZs+erQYNGujkyZOFZk5OTtbatWvl7Oysjh073rSs9kLhGwAAAAAAAABKgJubmwIDA1W5cmU1atRIL7/8spYuXaqVK1cqISFBhw8flslk0u7du83HpKWlyWQyacOGDeaxffv2qUOHDvLx8ZG3t7fuv/9+HTp0qNBr7ty5UwEBAXrttdfMYyaTSYGBgQoKClKtWrXUv39/bd26VZmZmRoxYkShmQMDA9WgQQONHDlSx44d06lTp+z62pQ0Ct8AAAAAAAAAcJO0bNlS9evX16JFi6yaf+LECT3wwAMqW7as1q1bp507d6pfv36FrhjfsGGDWrVqpQkTJmjMmDHXPG9AQIB69eqlb775Rrm5uYXOyczM1Ny5c3XHHXeoQoUKVuW9VdDjGwAAAAAAAABuopo1a+rXX3+1au77778vX19fzZ8/Xy4uLpKkGjVqFJi3dOlSPfHEE/r3v/+txx57zOoc58+f15kzZxQQECBJWrZsmby8vCRJWVlZCgoK0rJly25aT3J7ofANAAAAALeJiFkRpR0BQBES+ySWdgQAtxHDMGQymayau3v3bt1///3mondhfvrpJy1btkxfffWVunbtalMOSRZZoqOj9cEHH0iSzp49qxkzZigmJkY///yzQkNDrT53abu9yvQAAAAAAAAAcJs7cOCAwsPDzauo8wvQkpSTk2Mx193d/brnq169umrWrKnPPvtMly5dsimHj4+PRRsTT09P3XHHHbrjjjt0zz336NNPP1VWVpY+/vhjq897K6DwDQAAAAAAAAA3ybp165SYmKju3burYsWKkqTk5GTz/itvdClJ9erV0+bNmwsUxK/k7++vdevW6dChQ3r00UevOTdfamqqvvjiC3Xp0uWabUxMJpPKlCmjCxcuXPectxIK3wAAAAAAAABQArKzs5WSkqITJ05o165dmjRpkjp37qyOHTuqd+/ecnd3V7NmzTR58mTt379fmzZt0v/93/9ZnOP5559XRkaGevTooR07dujgwYP6/PPP9dtvv1nMCwgI0Lp16/Sf//xHjz32mMXNLw3DUEpKipKTk3XgwAF99tlnioyMlK+vryZPnlxo5pSUFB04cEAvvPCCMjMzFRsbW3IvVAmg8A0AAAAAAAAAJWDVqlUKCgpSWFiY2rVrp/Xr1+vdd9/V0qVL5eTkJEn67LPPlJOToyZNmmjw4MF69dVXLc5RoUIFrVu3TpmZmWrRooUaN26sjz/+uNCe34GBgeYV5b169VJubq4kKSMjQ0FBQapcubLuvfde/fvf/1afPn30yy+/KCgoqNDMQUFBatq0qbZv366vvvpKUVFRJfMilRCTcWUDmf9RGRkZ8vX1VXp6unx8fEo7DgAAAAAUiptbArcubm4JlIyLFy8qKSlJ4eHhKlu2bGnHwU1yrd+7tbVcVnwDAAAAAAAAABwKhW8AAAAAAAAAgEOh8A0AAAAAAAAAcCgUvgEAAAAAAAAADoXCNwAAAAAAAADAoVD4BgAAAAAAAAA4FArfAAAAAAAAAACHQuEbAAAAAAAAAOBQKHwDAAAAAAAAABwKhW8AAAAAAAAAcDBRUVEaMmRIaccoNc6lHQAAAAAAAAAAbDbe9yZfL93mQ1JTUzV27FitXLlSf/31l8qXL6/69etr/Pjxuvfee0sgJPJR+AYAAAAAAACAEtC9e3fl5ORo1qxZqlatmv766y+tXbtWZ8+eLbFr5uTkyMXFpcTOf7ug1QkAAAAAAAAA2FlaWpq2bNmi119/XdHR0QoNDdU999yj0aNHq0OHDpIkk8mkDz74QDExMXJ3d1d4eLi++uori/OMHDlSNWrUkIeHh6pVq6axY8cqJyfHvH/8+PFq0KCBPvvsM1WrVk1ubm4yDKNAnlWrVsnX11ezZ88u2Sd+i6DwDQAAAAAAAAB25uXlJS8vLy1ZskTZ2dlFzhs7dqy6d++uPXv26PHHH9djjz2mAwcOmPd7e3srISFB+/fv1zvvvKOPP/5YU6dOtTjHH3/8oS+//FILFy7U7t27C1xj/vz5euSRRzR79mz17t3bbs/xVkbhGwAAAAAAAADszNnZWQkJCZo1a5bKlSun5s2b6+WXX9avv/5qMe/hhx/Wk08+qRo1amjixIlq0qSJpk+fbt7/f//3f4qMjFRYWJhiY2M1bNgwffnllxbnuHTpkj7//HM1bNhQ9erVk8lkMu+bMWOGnnnmGS1dulSdO3cu2Sd9C6HwDQAAAAAAAAAloHv37jp58qS++eYbtW3bVhs2bFCjRo2UkJBgnnP1TS7vvfdeixXfX3/9te677z4FBgbKy8tLY8eO1dGjRy2OCQ0NVcWKFQtcf+HChRoyZIi+++47RUdH2/fJ3eIofAMAAAAAAABACSlbtqxat26tf/3rX9q6davi4uI0bty4ax6Tv2L7xx9/VI8ePRQTE6Nly5bpl19+0ZgxY3Tp0iWL+Z6enoWep0GDBqpYsaJmzpxZaN9vR1aqhe9NmzYpNjZWwcHBMplMWrJkicV+k8lU6OONN94wz4mKiiqwv0ePHjf5mQAAAAAAAADA9dWuXVtZWVnm7R9//NFi/48//qiaNWtKkn744QeFhoZqzJgxatKkie68804dOXLE6mtVr15d69ev19KlS/XCCy/Y5wncJpxL8+JZWVmqX7+++vbtq+7duxfYn5ycbLG9cuVK9e/fv8DcAQMG6JVXXjFvu7u7l0xgAAAAAAAAALDCmTNn9PDDD6tfv36qV6+evL29tWPHDk2ZMsWi1/ZXX32lJk2a6L777tPcuXP1888/69NPP5Uk3XHHHTp69Kjmz5+vu+++W8uXL9fixYttylGjRg2tX79eUVFRcnZ21rRp0+z5NG9ZpVr4jomJUUxMTJH7AwMDLbaXLl2q6OhoVatWzWLcw8OjwFwAAAAAAAAAKC1eXl5q2rSppk6dqkOHDiknJ0chISEaMGCAXn75ZfO8CRMmaP78+Ro4cKACAwM1d+5c1a5dW5LUuXNnvfjii3r++eeVnZ2tDh06aOzYsRo/frxNWe666y6tW7dOUVFRcnJy0ltvvWXPp3pLMhm3SHMXk8mkxYsXq0uXLoXu/+uvv1SlShXNmjVLPXv2NI9HRUVp3759MgxDlSpVUkxMjMaNGydvb+8ir5Wdna3s7GzzdkZGhkJCQpSeni4fHx+7PScAAAAAsKeIWRGlHQFAERL7JJZ2BMAhXbx4UUlJSQoPD1fZsmVLO47dXa8m+r/qWr/3jIwM+fr6XreWW6orvm0xa9YseXt7q1u3bhbjvXr1Unh4uAIDA7V3716NHj1ae/bs0Zo1a4o8V3x8vCZMmFDSkQEAAAAAAAAApeC2KXx/9tln6tWrV4EK/4ABA8w/161bV3feeaeaNGmiXbt2qVGjRoWea/To0Ro6dKh5O3/FNwAAAAAAAADg9ndbFL43b96s3377TQsWLLju3EaNGsnFxUUHDx4ssvDt5uYmNzc3e8cEAAAAAAAAAKvdIl2oHVKZ0g5gjU8//VSNGzdW/fr1rzt33759ysnJUVBQ0E1IBgAAAAAAAAC41ZTqiu/MzEz98ccf5u2kpCTt3r1bfn5+qlq1qqR/2pB89dVXhd5p9NChQ5o7d67at28vf39/7d+/X8OGDVPDhg3VvHnzm/Y8AAAAAAAAAAC3jlItfO/YsUPR0dHm7fy+23369FFCQoIkaf78+TIMQ4899liB411dXbV27Vq98847yszMVEhIiDp06KBx48bJycnppjwHAAAAAAAAAMCtpVQL31FRUdftY/PUU0/pqaeeKnRfSEiINm7cWBLRAAAAAAAAAAC3qduixzcAAAAAAAAAANai8A0AAAAAAAAAcCgUvgEAAAAAAADAAf3www+KiIiQi4uLunTpcsPnS0hIULly5W74PDdDqfb4BgAAAAAAAIDiiJgVcVOvl9gn0ab5cXFxmjVrliTJ2dlZfn5+qlevnh577DHFxcWpTBnr1iQnJCRoyJAhSktLszWyhg4dqgYNGmjlypXy8vKy+firPfroo2rfvv0Nn+dmYMU3AAAAAAAAAJSAdu3aKTk5WYcPH9bKlSsVHR2twYMHq2PHjrp8+XKJX//QoUNq2bKlqlSpYpeV2u7u7goICLjxYDcBhW8AAAAAAAAAKAFubm4KDAxU5cqV1ahRI7388staunSpVq5cqYSEBEnS22+/rYiICHl6eiokJEQDBw5UZmamJGnDhg3q27ev0tPTZTKZZDKZNH78eEnSnDlz1KRJE3l7eyswMFA9e/ZUamqqJOnw4cMymUw6c+aM+vXrJ5PJpISEhEJblSxZskQmk8m8vWfPHkVHR8vb21s+Pj5q3LixduzYIanwVicffPCBqlevLldXV9111136/PPPLfabTCZ98skn6tq1qzw8PHTnnXfqm2++sdMrXDQK3wAAAAAAAABwk7Rs2VL169fXokWLJEllypTRu+++q71792rWrFlat26dRowYIUmKjIzUtGnT5OPjo+TkZCUnJ2v48OGSpEuXLmnixInas2ePlixZoqSkJMXFxUmSQkJClJycLB8fH02bNk3Jycl69NFHrcrXq1cvValSRdu3b9fOnTs1atQoubi4FDp38eLFGjx4sIYNG6a9e/fq6aefVt++fbV+/XqLeRMmTNAjjzyiX3/9Ve3bt1evXr109uzZ4rx8VqPHNwAAAAAAAADcRDVr1tSvv/4qSRoyZIh5PDw8XBMnTtSzzz6rGTNmyNXVVb6+vjKZTAoMDLQ4R79+/cw/V6tWTe+++67uueceZWZmysvLS4GBgTKZTPL19S1w7LUcPXpUL730kmrWrClJuvPOO4uc++abbyouLk4DBw6U9E9P8R9//FFvvvmmoqOjzfPi4uL02GOPSZImTZqk6dOn6+eff1a7du2szmUrVnwDAAAAAAAAwE1kGIa5vcj69evVunVrVa5cWd7e3urdu7fOnDmjrKysa57jl19+UefOnRUaGipvb29FRUVJ+qdwfSOGDh2qJ598Ug8++KAmT56sQ4cOFTn3wIEDat68ucVY8+bNdeDAAYuxevXqmX/29PSUt7e3uS1LSaHwDQAAAAAAAAA30YEDBxQeHq4jR46offv2qlu3rhYuXKidO3fq/ffflyTl5OQUeXxWVpbatGkjLy8vzZkzR9u3b9fixYsl/dMCpShlypSRYRgWY1dfZ/z48dq3b586dOigdevWqXbt2uZzF+bK/uCSZVE/39WtUkwmk/Ly8oo8pz1Q+AYAAAAAAACAm2TdunVKTExU9+7dtWPHDl2+fFlvvfWWmjVrpho1aujkyZMW811dXZWbm2sx9p///EenT5/W5MmTdf/996tmzZpWraCuWLGizp8/b7GafPfu3QXm1ahRQy+++KK+++47devWTTNnziz0fLVq1dKWLVssxrZu3apatWpdN0tJo8c3AAAAAAAAAJSA7OxspaSkKDc3V3/99ZdWrVql+Ph4dezYUb1791ZiYqIuX76s6dOnKzY2Vj/88IM+/PBDi3OEhYUpMzNTa9euVf369eXh4aGqVavK1dVV06dP1zPPPKO9e/dq4sSJ183TtGlTeXh46OWXX9YLL7ygn3/+WQkJCeb9Fy5c0EsvvaSHHnpI4eHhOn78uLZv367u3bsXer6XXnpJjzzyiBo1aqRWrVrp22+/1aJFi/T999/f0OtmD6z4BgAAAAAAAIASsGrVKgUFBSksLEzt2rXT+vXr9e6772rp0qVycnJSgwYN9Pbbb+v1119X3bp1NXfuXMXHx1ucIzIyUs8884weffRRVaxYUVOmTFHFihWVkJCgr776SrVr19bkyZP15ptvXjePn5+f5syZoxUrVigiIkLz5s3T+PHjzfudnJx05swZ9e7dWzVq1NAjjzyimJgYTZgwodDzdenSRe+8847eeOMN1alTR//+9781c+ZMc7/x0mQyrm7q8j8oIyNDvr6+Sk9Pl4+PT2nHAQAAAIBCRcyKKO0IAIqQ2CextCMADunixYtKSkpSeHi4ypYtW9pxcJNc6/dubS2XFd8AAAAAAAAAAIdC4RsAAAAAAAAA4FAofAMAAAAAAAAAHIpNhe/Lly9r1qxZSklJKak8AAAAAAAAAADcEJsK387Oznr22WeVnZ1dUnkAAAAAAAAAwIJhGKUdATeRPX7fNrc6adq0qXbv3n3DFwYAAAAAAACAa3FxcZEk/f3336WcBDdT/u87//dfHM62HjBw4EANHTpUx44dU+PGjeXp6Wmxv169esUOAwAAAAAAAAD5nJycVK5cOaWmpkqSPDw8ZDKZSjkVSophGPr777+VmpqqcuXKycnJqdjnsrnw/eijj0qSBg0aZB4zmUwyDEMmk0m5ubnFDgMAAAAAAAAAVwoMDJQkc/Ebjq9cuXLm33tx2Vz4TkpKuqELAgAAAAAAAIC1TCaTgoKCFBAQoJycnNKOgxLm4uJyQyu989lc+A4NDb3hiwIAAAAAAACALZycnOxSEMX/BptvbilJn3/+uZo3b67g4GAdOXJEkjRt2jQtXbrUruEAAAAAAAAAALCVzYXvDz74QEOHDlX79u2VlpZm7uldrlw5TZs2zd75AAAAAAAAAACwic2F7+nTp+vjjz/WmDFjLP60oEmTJkpMTLRrOAAAAAAAAAAAbGVz4TspKUkNGzYsMO7m5qasrCy7hAIAAAAAAAAAoLhsLnyHh4dr9+7dBcZXrlyp2rVr2yMTAAAAAAAAAADF5mzrAS+99JKee+45Xbx4UYZh6Oeff9a8efMUHx+vTz75pCQyAgAAAAAAAABgNZsL33379tXly5c1YsQI/f333+rZs6cqV66sd955Rz169CiJjAAAAAAAAAAAWM3mwrckDRgwQAMGDNDp06eVl5engIAAe+cCAAAAAAAAAKBYbO7x3bJlS6WlpUmS/P39zUXvjIwMtWzZ0q7hAAAAAAAAAACwlc2F7w0bNujSpUsFxi9evKjNmzfbJRQAAAAAAAAAAMVldauTX3/91fzz/v37lZKSYt7Ozc3VqlWrVLlyZfumAwAAAAAAAADARlYXvhs0aCCTySSTyVRoSxN3d3dNnz7druEAAAAAAAAAALCV1YXvpKQkGYahatWq6eeff1bFihXN+1xdXRUQECAnJ6cSCQkAAAAAAAAAgLWs7vEdGhqqsLAwrV+/Xg0aNFBoaKj5ERQUJEnatGmTTRfftGmTYmNjFRwcLJPJpCVLlljsj4uLM68yz380a9bMYk52drZeeOEF+fv7y9PTU506ddLx48dtygEAAAAAAAAAcBw239yyZcuWOnv2bIHxtLQ0RUdH23SurKws1a9fX++9916Rc9q1a6fk5GTzY8WKFRb7hwwZosWLF2v+/PnasmWLMjMz1bFjR+Xm5tqUBQAAAAAAAADgGKxudZLPMAyZTKYC42fOnJGnp6dN54qJiVFMTMw157i5uSkwMLDQfenp6fr000/1+eef68EHH5QkzZkzRyEhIfr+++/Vtm1bm/IAAAAAAAAAAG5/Vhe+u3XrJkkymUyKi4uTm5ubeV9ubq5+/fVXRUZG2j3ghg0bFBAQoHLlyqlFixZ67bXXFBAQIEnauXOncnJy1KZNG/P84OBg1a1bV1u3bqXwDQAAAAAAAAD/g6wufPv6+kr6Z8W3t7e33N3dzftcXV3VrFkzDRgwwK7hYmJi9PDDDys0NFRJSUkaO3asWrZsqZ07d8rNzU0pKSlydXVV+fLlLY6rVKmSUlJSijxvdna2srOzzdsZGRl2zQ0AAAAAAAAAKD1WF75nzpwpSQoLC9Pw4cNtbmtSHI8++qj557p166pJkyYKDQ3V8uXLzSvQC1NUO5Z88fHxmjBhgl2zAgAAAAAAAABuDTbf3HLcuHFyc3PT999/r3//+986f/68JOnkyZPKzMy0e8ArBQUFKTQ0VAcPHpQkBQYG6tKlSzp37pzFvNTUVFWqVKnI84wePVrp6enmx7Fjx0o0NwAAAAAAAADg5rG58H3kyBFFRESoc+fOeu6553Tq1ClJ0pQpUzR8+HC7B7zSmTNndOzYMQUFBUmSGjduLBcXF61Zs8Y8Jzk5WXv37r1mv3E3Nzf5+PhYPAAAAAAAAAAAjsHqVif5Bg8erCZNmmjPnj2qUKGCebxr16568sknbTpXZmam/vjjD/N2UlKSdu/eLT8/P/n5+Wn8+PHq3r27goKCdPjwYb388svy9/dX165dJf3Td7x///4aNmyYKlSoID8/Pw0fPlwRERF68MEHbX1qAAAAAAAAAAAHYHPhe8uWLfrhhx/k6upqMR4aGqoTJ07YdK4dO3YoOjravD106FBJUp8+ffTBBx8oMTFRs2fPVlpamoKCghQdHa0FCxbI29vbfMzUqVPl7OysRx55RBcuXFCrVq2UkJAgJycnW58aAAAAAAAAAMAB2Fz4zsvLU25uboHx48ePWxSkrREVFSXDMIrcv3r16uueo2zZspo+fbqmT59u07UBAAAAAAAAAI7J5h7frVu31rRp08zbJpNJmZmZGjdunNq3b2/PbAAAAAAAAAAA2MzmFd9Tp05VdHS0ateurYsXL6pnz546ePCg/P39NW/evJLICAAAAAAAAACA1WwufAcHB2v37t2aP3++du7cqby8PPXv31+9evWSu7t7SWQEAAAAAAAAAMBqNhe+Jcnd3V19+/ZV37597Z0HAAAAAAAAAIAbYnPh+8yZM6pQoYIk6dixY/r444914cIFxcbG6oEHHrB7QAAAAAAAAAAAbGH1zS0TExMVFhamgIAA1axZU7t379bdd9+tqVOn6qOPPlLLli21ZMmSEowKAAAAAAAAAMD1WV34HjFihCIiIrRx40ZFRUWpY8eOat++vdLT03Xu3Dk9/fTTmjx5cklmBQAAAAAAAADguqxudbJ9+3atW7dO9erVU4MGDfTRRx9p4MCBKlPmn9r5Cy+8oGbNmpVYUAAAAAAAAAAArGH1iu+zZ88qMDBQkuTl5SVPT0/5+fmZ95cvX17nz5+3f0IAAAAAAAAAAGxgdeFbkkwm0zW3AQAAAAAAAAAobVa3OpGkuLg4ubm5SZIuXryoZ555Rp6enpKk7Oxs+6cDAAAAAAAAAMBGVhe++/TpY7H9+OOPF5jTu3fvG08EAAAAAAAAAMANsLrwPXPmzJLMAQAAAAAAAACAXdjU4xsAAAAAAAAAgFsdhW8AAAAAAAAAgEOh8A0AAAAAAAAAcCgUvgEAAAAAAAAADoXCNwAAAAAAAADAodhc+J41a5aWL19u3h4xYoTKlSunyMhIHTlyxK7hAAAAAAAAAACwlc2F70mTJsnd3V2StG3bNr333nuaMmWK/P399eKLL9o9IAAAAAAAAAAAtnC29YBjx47pjjvukCQtWbJEDz30kJ566ik1b95cUVFR9s4HAAAAAAAAAIBNbF7x7eXlpTNnzkiSvvvuOz344IOSpLJly+rChQv2TQcAAAAAAAAAgI1sXvHdunVrPfnkk2rYsKF+//13dejQQZK0b98+hYWF2TsfAAAAAAAAAAA2sXnF9/vvv697771Xp06d0sKFC1WhQgVJ0s6dO/XYY4/ZPSAAAAAAAAAAALYwGYZhlHaI0paRkSFfX1+lp6fLx8entOMAAAAAQKEiZkWUdgQARUjsk1jaEQDgf4K1tVyrWp38+uuvqlu3rsqUKaNff/31mnPr1atnW1IAAAAAAAAAAOzIqsJ3gwYNlJKSooCAADVo0EAmk0lXLhTP3zaZTMrNzS2xsAAAAAAAAAAAXI9Vhe+kpCRVrFjR/DMAAAAAAAAAALcqqwrfoaGhhf4MAAAAAAAAAMCtpkxpBwAAAAAAAAAAwJ4ofAMAAAAAAAAAHAqFbwAAAAAAAACAQ7Gp8J2bm6uNGzfq3LlzJZUHAAAAAAAAAIAbYlPh28nJSW3btlVaWloJxQEAAAAAAAAA4MbY3OokIiJCf/75Z0lkAQAAAAAAAADghtlc+H7ttdc0fPhwLVu2TMnJycrIyLB4AAAAAAAAAABQmpxtPaBdu3aSpE6dOslkMpnHDcOQyWRSbm6u/dIBAAAAAAAAAGAjmwvf69evL4kcAAAAuBWM9y3tBACuJbxqaScAAAC4Ldjc6qRFixbXfNhi06ZNio2NVXBwsEwmk5YsWWLel5OTo5EjRyoiIkKenp4KDg5W7969dfLkSYtzREVFyWQyWTx69Ohh69MCAAAAAAAAADgImwvfkrR582Y9/vjjioyM1IkTJyRJn3/+ubZs2WLTebKyslS/fn299957Bfb9/fff2rVrl8aOHatdu3Zp0aJF+v3339WpU6cCcwcMGKDk5GTz49///ndxnhYAAAAAAAAAwAHY3Opk4cKFeuKJJ9SrVy/t2rVL2dnZkqTz589r0qRJWrFihdXniomJUUxMTKH7fH19tWbNGoux6dOn65577tHRo0dVtep//8TPw8NDgYGBtj4VAAAAAAAAAIADsnnF96uvvqoPP/xQH3/8sVxcXMzjkZGR2rVrl13DXS09PV0mk0nlypWzGJ87d678/f1Vp04dDR8+XOfPn7/mebKzs5WRkWHxAAAAAAAAAAA4BptXfP/222964IEHCoz7+PgoLS3NHpkKdfHiRY0aNUo9e/aUj4+PebxXr14KDw9XYGCg9u7dq9GjR2vPnj0FVotfKT4+XhMmTCixrAAAAAAAAACA0mNz4TsoKEh//PGHwsLCLMa3bNmiatWq2SuXhZycHPXo0UN5eXmaMWOGxb4BAwaYf65bt67uvPNONWnSRLt27VKjRo0KPd/o0aM1dOhQ83ZGRoZCQkJKJDsAAAAAAAAA4OayudXJ008/rcGDB+unn36SyWTSyZMnNXfuXA0fPlwDBw60e8CcnBw98sgjSkpK0po1ayxWexemUaNGcnFx0cGDB4uc4+bmJh8fH4sHAAAAAAAAAMAx2Lzie8SIEUpPT1d0dLQuXryoBx54QG5ubho+fLief/55u4bLL3ofPHhQ69evV4UKFa57zL59+5STk6OgoCC7ZgEAAAAAAAAA3B5sLnxL0muvvaYxY8Zo//79ysvLU+3ateXl5WXzeTIzM/XHH3+Yt5OSkrR79275+fkpODhYDz30kHbt2qVly5YpNzdXKSkpkiQ/Pz+5urrq0KFDmjt3rtq3by9/f3/t379fw4YNU8OGDdW8efPiPDUAAAAAAAAAwG3O5sL3mjVr1Lx5c3l4eKhJkyY3dPEdO3YoOjravJ3fd7tPnz4aP368vvnmG0lSgwYNLI5bv369oqKi5OrqqrVr1+qdd95RZmamQkJC1KFDB40bN05OTk43lA0AAAAAAAAAcHuyufDdvXt3ZWdnq3HjxmrRooWioqLUvHnzYq34joqKkmEYRe6/1j5JCgkJ0caNG22+LgAAAAAAAADAcdl8c8tz585pw4YN6tSpk3755Rc9/PDD8vPzU7NmzTRq1KiSyAgAAAAAAAAAgNVMxvWWVV/H3r179eabb2ru3LnKy8tTbm6uvbLdNBkZGfL19VV6erp8fHxKOw4AAEDpGe9b2gkAXENEeNXSjgCgCIl9Eks7AgD8T7C2lmtzq5MDBw5o48aN2rBhgzZu3Kjc3Fzdd999euutt9SiRYsbCg0AAAAAAAAAwI2yufBdp04dVaxYUUOGDNHYsWNVp06dksgFAAAAAAAAAECx2Nzje9CgQapcubLGjx+vfv36aeTIkVq5cqUyMzNLIh8AAAAAAAAAADaxufA9bdo07dq1S3/99Zf+7//+T7m5ufrXv/4lf39/NWvWrCQyAgAAAAAAAABgNZsL3/ny8vJ0+fJlXbp0SdnZ2crJydHhw4ftGA0AAAAAAAAAANvZXPgePHiw6tevr4CAAD399NM6efKknnrqKe3Zs0cpKSklkREAAAAAAAAAAKvZfHPLEydOaMCAAYqKilLdunVLIhMAAAAAAAAAAMVmc+H766+/LokcAAAAAAAAAADYhc2Fb0k6dOiQpk2bpgMHDshkMqlWrVoaPHiwqlevbu98AAAAAAAAAADYxOYe36tXr1bt2rX1888/q169eqpbt65++ukn1alTR2vWrCmJjAAAAAAAAAAAWM3mFd+jRo3Siy++qMmTJxcYHzlypFq3bm23cAAAAAAAAAAA2MrmFd8HDhxQ//79C4z369dP+/fvt0soAAAAAAAAAACKy+bCd8WKFbV79+4C47t371ZAQIA9MgEAAAAAAAAAUGw2tzoZMGCAnnrqKf3555+KjIyUyWTSli1b9Prrr2vYsGElkREAAAAAAAAAAKvZXPgeO3asvL299dZbb2n06NGSpODgYI0fP16DBw+2e0AAAAAAAAAAAGxhc6sTk8mkF198UcePH1d6errS09N1/PhxPfnkk9q0aVNJZAQAAAAAAAAAwGo2r/i+kre3t/nnP/74Q9HR0crNzb3hUAAAAAAAAAAAFJfNK74BAAAAAAAAALiVUfgGAAAAAAAAADgUCt8AAAAAAAAAAIdidY/vb7755pr7k5KSbjgMAOB/Q9io5aUdAUARDpct7QQAAAAAcOOsLnx36dLlunNMJtONZAEAAAAAAAAA4IZZXfjOy8sryRwAAAAAAAAAANgFPb4BAAAAAAAAAA6FwjcAAAAAAAAAwKFQ+AYAAAAAAAAAOBQK3wAAAAAAAAAAh0LhGwAAAAAAAADgUCh8AwAAAAAAAAAcil0L3+Hh4erfv79OnDhhz9MCAAAAAAAAAGA1uxa++/Tpo7y8PD3wwAP2PC0AAAAAAAAAAFZztufJxo8fb8/TAQAAAAAAAABgM3p8AwAAAAAAAAAcilUrvocOHWr1Cd9+++1ihwEAAAAAAAAA4EZZVfj+5ZdfLLZ37typ3Nxc3XXXXZKk33//XU5OTmrcuLH9EwIAAAAAAAAAYAOrWp2sX7/e/IiNjVVUVJSOHz+uXbt2adeuXTp27Jiio6PVoUMHmy6+adMmxcbGKjg4WCaTSUuWLLHYbxiGxo8fr+DgYLm7uysqKkr79u2zmJOdna0XXnhB/v7+8vT0VKdOnXT8+HGbcgAAAAAAAAAAHIfNPb7feustxcfHq3z58uax8uXL69VXX9Vbb71l07mysrJUv359vffee4XunzJlit5++22999572r59uwIDA9W6dWudP3/ePGfIkCFavHix5s+fry1btigzM1MdO3ZUbm6urU8NAAAAAAAAAOAArGp1cqWMjAz99ddfqlOnjsV4amqqRUHaGjExMYqJiSl0n2EYmjZtmsaMGaNu3bpJkmbNmqVKlSrpiy++0NNPP6309HR9+umn+vzzz/Xggw9KkubMmaOQkBB9//33atu2ra1PDwAAAAAAAABwm7N5xXfXrl3Vt29fff311zp+/LiOHz+ur7/+Wv379zcXqO0hKSlJKSkpatOmjXnMzc1NLVq00NatWyX902s8JyfHYk5wcLDq1q1rngMAAAAAAAAA+N9i84rvDz/8UMOHD9fjjz+unJycf07i7Kz+/fvrjTfesFuwlJQUSVKlSpUsxitVqqQjR46Y57i6ulq0Xcmfk398YbKzs5WdnW3ezsjIsFdsAAAAAAAAAEAps3nFt4eHh2bMmKEzZ87ol19+0a5du3T27FnNmDFDnp6edg9oMpkstg3DKDB2tevNiY+Pl6+vr/kREhJil6wAAAAAAAAAgNJnc+E7n6enp+rVq6f69euXSME7MDBQkgqs3E5NTTWvAg8MDNSlS5d07ty5IucUZvTo0UpPTzc/jh07Zuf0AAAAAAAAAIDSYnPhOysrS2PHjlVkZKTuuOMOVatWzeJhL+Hh4QoMDNSaNWvMY5cuXdLGjRsVGRkpSWrcuLFcXFws5iQnJ2vv3r3mOYVxc3OTj4+PxQMAAAAAAAAA4Bhs7vH95JNPauPGjXriiScUFBR03bYj15KZmak//vjDvJ2UlKTdu3fLz89PVatW1ZAhQzRp0iTdeeeduvPOOzVp0iR5eHioZ8+ekiRfX1/1799fw4YNU4UKFeTn56fhw4crIiJCDz74YLFzAQAAAAAAAABuXzYXvleuXKnly5erefPmN3zxHTt2KDo62rw9dOhQSVKfPn2UkJCgESNG6MKFCxo4cKDOnTunpk2b6rvvvpO3t7f5mKlTp8rZ2VmPPPKILly4oFatWikhIUFOTk43nA8AAAAAAAAAcPsxGYZh2HJAeHi4VqxYoVq1apVUppsuIyNDvr6+Sk9Pp+0JANwEYaOWl3YEAEU4XLZnaUcAcA0R4VVLOwKAIiT2SSztCADwP8HaWq7NPb4nTpyof/3rX/r7779vKCAAAAAAAAAAACXB5lYnb731lg4dOqRKlSopLCxMLi4uFvt37dplt3AAAAAAAAAAANjK5sJ3ly5dSiAGAAAAAAAAAAD2YXPhe9y4cSWRAwAAAAAAAAAAu7C58J1v586dOnDggEwmk2rXrq2GDRvaMxcAAAAAAAAAAMVic+E7NTVVPXr00IYNG1SuXDkZhqH09HRFR0dr/vz5qlixYknkBAAAAAAAAADAKmVsPeCFF15QRkaG9u3bp7Nnz+rcuXPau3evMjIyNGjQoJLICAAAAAAAAACA1Wxe8b1q1Sp9//33qlWrlnmsdu3aev/999WmTRu7hgMAAAAAAAAAwFY2r/jOy8uTi4tLgXEXFxfl5eXZJRQAAAAAAAAAAMVlc+G7ZcuWGjx4sE6ePGkeO3HihF588UW1atXKruEAAAAAAAAAALCVzYXv9957T+fPn1dYWJiqV6+uO+64Q+Hh4Tp//rymT59eEhkBAAAAAAAAALCazT2+Q0JCtGvXLq1Zs0b/+c9/ZBiGateurQcffLAk8gEAAAAAAAAAYBObC9/5WrdurdatW9szCwAAAAAAAAAAN8zmVieDBg3Su+++W2D8vffe05AhQ+yRCQAAAAAAAACAYrO58L1w4UI1b968wHhkZKS+/vpru4QCAAAAAAAAAKC4bC58nzlzRr6+vgXGfXx8dPr0abuEAgAAAAAAAACguGwufN9xxx1atWpVgfGVK1eqWrVqdgkFAAAAAAAAAEBx2Xxzy6FDh+r555/XqVOn1LJlS0nS2rVr9dZbb2natGn2zgcAAAAAAAAAgE1sLnz369dP2dnZeu211zRx4kRJUlhYmD744AP17t3b7gEBAAAAAAAAALCFzYVvSXr22Wf17LPP6tSpU3J3d5eXl5e9cwEAAAAAAAAAUCw29/iWpMuXL+v777/XokWLZBiGJOnkyZPKzMy0azgAAAAAAAAAAGxl84rvI0eOqF27djp69Kiys7PVunVreXt7a8qUKbp48aI+/PDDksgJAAAAAAAAAIBVbF7xPXjwYDVp0kTnzp2Tu7u7ebxr165au3atXcMBAAAAAAAAAGArm1d8b9myRT/88INcXV0txkNDQ3XixAm7BQMAAAAAAAAAoDhsXvGdl5en3NzcAuPHjx+Xt7e3XUIBAAAAAAAAAFBcNhe+W7durWnTppm3TSaTMjMzNW7cOLVv396e2QAAAAAAAAAAsJnNrU6mTp2q6Oho1a5dWxcvXlTPnj118OBB+fv7a968eSWREQAAAAAAAAAAq9lc+A4ODtbu3bs1f/587dy5U3l5eerfv7969eplcbNLAAAAAAAAAABKg82Fb0lyd3dX37591bdvX3vnAQAAAAAAAADghljd4/uPP/7Qzp07LcbWrl2r6Oho3XPPPZo0aZLdwwEAAAAAAAAAYCurC98vvfSSlixZYt5OSkpSbGysXF1dde+99yo+Pt7ippcAAAAAAAAAAJQGq1ud7NixQyNGjDBvz507VzVq1NDq1aslSfXq1dP06dM1ZMgQu4cEAAAAAAAAAMBaVq/4Pn36tKpUqWLeXr9+vWJjY83bUVFROnz4sF3DAQAAAAAAAABgK6sL335+fkpOTpYk5eXlaceOHWratKl5/6VLl2QYhv0TAgAAAAAAAABgA6sL3y1atNDEiRN17NgxTZs2TXl5eYqOjjbv379/v8LCwkoiIwAAAAAAAAAAVrO6x/drr72m1q1bKywsTGXKlNG7774rT09P8/7PP/9cLVu2LJGQAAAAAAAAAABYy+rCd3h4uA4cOKD9+/erYsWKCg4Ottg/YcIEix7gAAAAAAAAAACUBqsL35Lk4uKi+vXrF7qvqHEAAAAAAAAAAG4mq3t8l5awsDCZTKYCj+eee06SFBcXV2Bfs2bNSjk1AAAAAAAAAKC02LTiuzRs375dubm55u29e/eqdevWevjhh81j7dq108yZM83brq6uNzUjAAAAAAAAAODWccsXvitWrGixPXnyZFWvXl0tWrQwj7m5uSkwMPBmRwMAAAAAAAAA3IJu+VYnV7p06ZLmzJmjfv36yWQymcc3bNiggIAA1ahRQwMGDFBqauo1z5Odna2MjAyLBwAAAAAAAADAMRRrxXdaWpp+/vlnpaamKi8vz2Jf79697RKsMEuWLFFaWpri4uLMYzExMXr44YcVGhqqpKQkjR07Vi1bttTOnTvl5uZW6Hni4+M1YcKEEssJAAAAAAAAACg9JsMwDFsO+Pbbb9WrVy9lZWXJ29vbYuW1yWTS2bNn7R4yX9u2beXq6qpvv/22yDnJyckKDQ3V/Pnz1a1bt0LnZGdnKzs727ydkZGhkJAQpaeny8fHx+65AQCWwkYtL+0IAIpwuGzP0o4A4BoiwquWdgQARUjsk1jaEQDgf0JGRoZ8fX2vW8u1ecX3sGHD1K9fP02aNEkeHh43FNIWR44c0ffff69FixZdc15QUJBCQ0N18ODBIue4ubkVuRocAAAAAAAAAHB7s7nH94kTJzRo0KCbWvSWpJkzZyogIEAdOnS45rwzZ87o2LFjCgoKuknJAAAAAAAAAAC3EpsL323bttWOHTtKIkuR8vLyNHPmTPXp00fOzv9dpJ6Zmanhw4dr27ZtOnz4sDZs2KDY2Fj5+/ura9euNzUjAAAAAAAAAODWYHOrkw4dOuill17S/v37FRERIRcXF4v9nTp1slu4fN9//72OHj2qfv36WYw7OTkpMTFRs2fPVlpamoKCghQdHa0FCxbI29vb7jkAAAAAAAAAALc+m29uWaZM0YvETSaTcnNzbzjUzWZtQ3QAgH1wc0vg1sXNLYFbGze3BG5d3NwSAG6OEru5ZV5e3g0FAwAAAAAAAACgJNnc4xsAAAAAAAAAgFuZVSu+3333XT311FMqW7as3n333WvOHTRokF2CAQAAAAAAAABQHFYVvqdOnapevXqpbNmymjp1apHzTCYThW8AAAAAAAAAQKmyqvCdlJRU6M8AAAAAAAAAANxq6PENAAAAAAAAAHAoFL4BAAAAAAAAAA6FwjcAAAAAAAAAwKFQ+AYAAAAAAAAAOBQK3wAAAAAAAAAAh+JcnIPS0tL0888/KzU1VXl5eRb7evfubZdgAAAAAAAAAAAUh82F72+//Va9evVSVlaWvL29ZTKZzPtMJhOFbwAAAAAAAABAqbK51cmwYcPUr18/nT9/XmlpaTp37pz5cfbs2ZLICAAAAAAAAACA1WwufJ84cUKDBg2Sh4dHSeQBAAAAAAAAAOCG2Fz4btu2rXbs2FESWQAAAAAAAAAAuGE29/ju0KGDXnrpJe3fv18RERFycXGx2N+pUye7hQMAAAAAAAAAwFY2F74HDBggSXrllVcK7DOZTMrNzb3xVAAAAAAAAAAAFJPNhe+8vLySyAEAAAAAAAAAgF3Y3OMbAAAAAAAAAIBbWbEK3xs3blRsbKzuuOMO3XnnnerUqZM2b95s72wAAAAAAAAAANjM5sL3nDlz9OCDD8rDw0ODBg3S888/L3d3d7Vq1UpffPFFSWQEAAAAAAAAAMBqNvf4fu211zRlyhS9+OKL5rHBgwfr7bff1sSJE9WzZ0+7BgQAAAAAAAAAwBY2r/j+888/FRsbW2C8U6dOSkpKsksoAAAAAAAAAACKy+bCd0hIiNauXVtgfO3atQoJCbFLKAAAAAAAAAAAisvmVifDhg3ToEGDtHv3bkVGRspkMmnLli1KSEjQO++8UxIZAQAAAAAAAACwms2F72effVaBgYF666239OWXX0qSatWqpQULFqhz5852DwgAAAAAAAAAgC1sLnxLUteuXdW1a1d7ZwEAAAAAAAAA4IbZ3OMbAAAAAAAAAIBbmVUrvv38/PT777/L399f5cuXl8lkKnLu2bNn7RYOAAAAAAAAAABbWVX4njp1qry9vc0/X6vwDQAAAAAAAABAabKq8N2nTx/zz3FxcSWVBQAAAAAAAACAG2Zzj28nJyelpqYWGD9z5oycnJzsEgoAAAAAAAAAgOKyufBtGEah49nZ2XJ1db3hQAAAAAAAAAAA3AirWp1I0rvvvitJMplM+uSTT+Tl5WXel5ubq02bNqlmzZr2TwgAAAAAAAAAgA2sLnxPnTpV0j8rvj/88EOLtiaurq4KCwvThx9+aP+EAAAAAAAAAADYwOrCd1JSkiQpOjpaixYtUvny5UssFAAAAAAAAAAAxWV14Tvf+vXrSyIHAAAAAAAAAAB2YXPhW5KOHz+ub775RkePHtWlS5cs9r399tt2CSZJ48eP14QJEyzGKlWqpJSUFEn/tF2ZMGGCPvroI507d05NmzbV+++/rzp16tgtAwAAAAAAAADg9mJz4Xvt2rXq1KmTwsPD9dtvv6lu3bo6fPiwDMNQo0aN7B6wTp06+v77783bV/YWnzJlit5++20lJCSoRo0aevXVV9W6dWv99ttv8vb2tnsWAAAAAAAAAMCtr4ytB4wePVrDhg3T3r17VbZsWS1cuFDHjh1TixYt9PDDD9s9oLOzswIDA82PihUrSvpntfe0adM0ZswYdevWTXXr1tWsWbP0999/64svvrB7DgAAAAAAAADA7cHmwveBAwfUp08fSf8UpS9cuCAvLy+98sorev311+0e8ODBgwoODlZ4eLh69OihP//8U9I/N9tMSUlRmzZtzHPd3NzUokULbd269ZrnzM7OVkZGhsUDAAAAAAAAAOAYbC58e3p6Kjs7W5IUHBysQ4cOmfedPn3afskkNW3aVLNnz9bq1av18ccfKyUlRZGRkTpz5oy5z3elSpUsjrmyB3hR4uPj5evra36EhITYNTcAAAAAAAAAoPTY3OO7WbNm+uGHH1S7dm116NBBw4YNU2JiohYtWqRmzZrZNVxMTIz554iICN17772qXr26Zs2aZb6WyWSyOMYwjAJjVxs9erSGDh1q3s7IyKD4DQAAAAAAAAAOwubC99tvv63MzExJ0vjx45WZmakFCxbojjvu0NSpU+0e8Eqenp6KiIjQwYMH1aVLF0lSSkqKgoKCzHNSU1MLrAK/mpubm9zc3EoyKgAAAAAAAACglNjU6iQ3N1fHjh0zr4728PDQjBkz9Ouvv2rRokUKDQ0tkZD5srOzdeDAAQUFBSk8PFyBgYFas2aNef+lS5e0ceNGRUZGlmgOAAAAAAAAAMCty6bCt5OTk9q2bau0tLQSimNp+PDh2rhxo5KSkvTTTz/poYceUkZGhvr06SOTyaQhQ4Zo0qRJWrx4sfbu3au4uDh5eHioZ8+eNyUfAAAAAAAAAODWY3Ork4iICP35558KDw8viTwWjh8/rscee0ynT59WxYoV1axZM/3444/mleUjRozQhQsXNHDgQJ07d05NmzbVd999J29v7xLPBgAAAAAAAAC4NZkMwzBsOeC7777TyJEjNXHiRDVu3Fienp4W+318fOwa8GbIyMiQr6+v0tPTb8v8AHC7CRu1vLQjACjC4bL85RxwK4sIr1raEQAUIbFPYmlHAID/CdbWcm1e8d2uXTtJUqdOnWQymczjhmHIZDIpNze3GHEBAAAAAAAAALAPmwvf69evL4kcAAAAAAAAAADYhc2F7xYtWpREDgAAAAAAAAAA7MLmwvemTZuuuf+BBx4odhgAAAAAAAAAAG6UzYXvqKioAmNX9vqmxzcAAAAAAAAAoDSVsfWAc+fOWTxSU1O1atUq3X333fruu+9KIiMAAAAAAAAAAFazecW3r69vgbHWrVvLzc1NL774onbu3GmXYAAAAAAAAAAAFIfNK76LUrFiRf3222/2Oh0AAAAAAAAAAMVi84rvX3/91WLbMAwlJydr8uTJql+/vt2CAQAAAAAAAABQHDYXvhs0aCCTySTDMCzGmzVrps8++8xuwQAAAAAAAAAAKA6bC99JSUkW22XKlFHFihVVtmxZu4UCAAAAAAAAAKC4bC58h4aGlkQOAAAAAAAAAADswqbCd15enhISErRo0SIdPnxYJpNJ4eHheuihh/TEE0/IZDKVVE4AAAAAAAAAAKxSxtqJhmGoU6dOevLJJ3XixAlFRESoTp06OnLkiOLi4tS1a9eSzAkAAAAAAAAAgFWsXvGdkJCgTZs2ae3atYqOjrbYt27dOnXp0kWzZ89W79697R4SAAAAAAAAAABrWb3ie968eXr55ZcLFL0lqWXLlho1apTmzp1r13AAAAAAAAAAANjK6sL3r7/+qnbt2hW5PyYmRnv27LFLKAAAAAAAAAAAisvqwvfZs2dVqVKlIvdXqlRJ586ds0soAAAAAAAAAACKy+rCd25urpydi24J7uTkpMuXL9slFAAAAAAAAAAAxWX1zS0Nw1BcXJzc3NwK3Z+dnW23UAAAAAAAAAAAFJfVhe8+ffpcd07v3r1vKAwAAAAAAAAAADfK6sL3zJkzSzIHAAAAAAAAAAB2YXWPbwAAAAAAAAAAbgcUvgEAAAAAAAAADoXCNwAAAAAAAADAoVD4BgAAAAAAAAA4FArfAAAAAAAAAACHQuEbAAAAAAAAAOBQKHwDAAAAAAAAABwKhW8AAAAAAAAAgEOh8A0AAAAAAAAAcCgUvgEAAAAAAAAADoXCNwAAAAAAAADAoVD4BgAAAAAAAAA4FArfAAAAAAAAAACHQuEbAAAAAAAAAOBQKHwDAAAAAAAAABzKLV34jo+P19133y1vb28FBASoS5cu+u233yzmxMXFyWQyWTyaNWtWSokBAAAAAAAAAKXtli58b9y4Uc8995x+/PFHrVmzRpcvX1abNm2UlZVlMa9du3ZKTk42P1asWFFKiQEAAAAAAAAApc25tANcy6pVqyy2Z86cqYCAAO3cuVMPPPCAedzNzU2BgYE3Ox4AAAAAAAAA4BZ0S6/4vlp6erokyc/Pz2J8w4YNCggIUI0aNTRgwAClpqaWRjwAAAAAAAAAwC3gll7xfSXDMDR06FDdd999qlu3rnk8JiZGDz/8sEJDQ5WUlKSxY8eqZcuW2rlzp9zc3Ao9V3Z2trKzs83bGRkZJZ4fAAAAAAAAAHBz3DaF7+eff16//vqrtmzZYjH+6KOPmn+uW7eumjRpotDQUC1fvlzdunUr9Fzx8fGaMGFCieYFAAAAAAAAAJSO26LVyQsvvKBvvvlG69evV5UqVa45NygoSKGhoTp48GCRc0aPHq309HTz49ixY/aODAAAAAAAAAAoJbf0im/DMPTCCy9o8eLF2rBhg8LDw697zJkzZ3Ts2DEFBQUVOcfNza3INigAAAAAAAAAgNvbLb3i+7nnntOcOXP0xRdfyNvbWykpKUpJSdGFCxckSZmZmRo+fLi2bdumw4cPa8OGDYqNjZW/v7+6du1ayukBAAAAAAAAAKXhll7x/cEHH0iSoqKiLMZnzpypuLg4OTk5KTExUbNnz1ZaWpqCgoIUHR2tBQsWyNvbuxQSAwAAAAAAAABK2y1d+DYM45r73d3dtXr16puUBgAAAAAAAABwO7ilW50AAAAAAAAAAGArCt8AAAAAAAAAAIdC4RsAAAAAAAAA4FAofAMAAAAAAAAAHAqFbwAAAAAAAACAQ6HwDQAAAAAAAABwKBS+AQAAAAAAAAAOhcI3AAAAAAAAAMChUPgGAAAAAAAAADgUCt8AAAAAAAAAAIdC4RsAAAAAAAAA4FAofAMAAAAAAAAAHAqFbwAAAAAAAACAQ6HwDQAAAAAAAABwKBS+AQAAAAAAAAAOhcI3AAAAAAAAAMChUPgGAAAAAAAAADgUCt8AAAAAAAAAAIdC4RsAAAAAAAAA4FAofAMAAAAAAAAAHAqFbwAAAAAAAACAQ6HwDQAAAAAAAABwKBS+AQAAAAAAAAAOhcI3AAAAAAAAAMChUPgGAAAAAAAAADgUCt8AAAAAAAAAAIdC4RsAAAAAAAAA4FAofAMAAAAAAAAAHAqFbwAAAAAAAACAQ6HwDQAAAAAAAABwKBS+AQAAAAAAAAAOhcI3AAAAAAAAAMChUPgGAAAAAAAAADgUCt8AAAAAAAAAAIdC4RsAAAAAAAAA4FAofAMAAAAAAAAAHAqFbwAAAAAAAACAQ6HwDQAAAAAAAABwKA5T+J4xY4bCw8NVtmxZNW7cWJs3by7tSAAAAAAAAACAUuAQhe8FCxZoyJAhGjNmjH755Rfdf//9iomJ0dGjR0s7GgAAAAAAAADgJnOIwvfbb7+t/v3768knn1StWrU0bdo0hYSE6IMPPijtaAAAAAAAAACAm8y5tAPcqEuXLmnnzp0aNWqUxXibNm20devWQo/Jzs5Wdna2eTs9PV2SlJGRUXJBAQBmedl/l3YEAEXIMBmlHQHANeReyC3tCACKQE0BAG6O/O9bw7j2/+9y2xe+T58+rdzcXFWqVMlivFKlSkpJSSn0mPj4eE2YMKHAeEhISIlkBAAAuF34lnYAANdxoLQDACiC77P8VxQAbqbz58/L17fo797bvvCdz2QyWWwbhlFgLN/o0aM1dOhQ83ZeXp7Onj2rChUqFHkMAAAAcDvJyMhQSEiIjh07Jh8fn9KOAwAAANiFYRg6f/68goODrznvti98+/v7y8nJqcDq7tTU1AKrwPO5ubnJzc3NYqxcuXIlFREAAAAoNT4+PhS+AQAA4FCutdI7321/c0tXV1c1btxYa9assRhfs2aNIiMjSykVAAAAAAAAAKC03PYrviVp6NCheuKJJ9SkSRPde++9+uijj3T06FE988wzpR0NAAAAAAAAAHCTOUTh+9FHH9WZM2f0yiuvKDk5WXXr1tWKFSsUGhpa2tEAAACAUuHm5qZx48YVaPEHAAAA/C8wGYZhlHYIAAAAAAAAAADs5bbv8Q0AAAAAAAAAwJUofAMAAAAAAAAAHAqFbwAAAAAAAACAQ6HwDQAAAAAAAABwKBS+AQAAAAc0Y8YMhYeHq2zZsmrcuLE2b95c2pEAAACAm4bCNwAAAOBgFixYoCFDhmjMmDH65ZdfdP/99ysmJkZHjx4t7WgAAADATWEyDMMo7RAAAAAA7Kdp06Zq1KiRPvjgA/NYrVq11KVLF8XHx5diMgAAAODmYMU3AAAA4EAuXbqknTt3qk2bNhbjbdq00datW0spFQAAAHBzUfgGAAAAHMjp06eVm5urSpUqWYxXqlRJKSkppZQKAAAAuLkofAMAAAAOyGQyWWwbhlFgDAAAAHBUFL4BAAAAB+Lv7y8nJ6cCq7tTU1MLrAIHAAAAHBWFbwAAAMCBuLq6qnHjxlqzZo3F+Jo1axQZGVlKqQAAAICby7m0AwAAAACwr6FDh+qJJ55QkyZNdO+99+qjjz7S0aNH9cwzz5R2NAAAAOCmoPANAAAAOJhHH31UZ86c0SuvvKLk5GTVrVtXK1asUGhoaGlHAwAAAG4Kk2EYRmmHAAAAAAAAAADAXujxDQAAAAAAAABwKBS+AQAAAAAAAAAOhcI3AAAAAAAAAMChUPgGAAAAAAAAADgUCt8AAAAAAAAAAIdC4RsAAAAAAAAA4FAofAMAAAAAAAAAHAqFbwAAAAAAAACAQ6HwDQAAAAAAAABwKBS+AQAAAAAAAAAOhcI3AAAAAAAAAMChUPgGAAAAAAAAADiU/wcGRNtO3wy1ywAAAABJRU5ErkJggg==\n"},"metadata":{}}],"execution_count":13,"metadata":{"jupyter":{"source_hidden":false,"outputs_hidden":false},"nteract":{"transient":{"deleting":false}}}}],"metadata":{"colab":{"provenance":[]},"kernelspec":{"name":"synapse_pyspark","language":"Python","display_name":"Synapse PySpark"},"widgets":{},"language_info":{"name":"python"},"kernel_info":{"name":"synapse_pyspark"},"save_output":true,"spark_compute":{"compute_id":"/trident/default","session_options":{"enableDebugMode":false,"conf":{}}},"notebook_environment":{},"synapse_widget":{"version":"0.1","state":{}},"trident":{"lakehouse":{"default_lakehouse":"ae4bae7b-ffe8-4416-a2c1-df3d95e95c46","known_lakehouses":[{"id":"ae4bae7b-ffe8-4416-a2c1-df3d95e95c46"}],"default_lakehouse_name":"TPCH_SF10","default_lakehouse_workspace_id":"17b12c5b-edd2-4d48-be12-6477d0ff0d91"}}},"nbformat":4,"nbformat_minor":0}
2 |
--------------------------------------------------------------------------------