mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-09 00:54:43 +00:00
9ec78855cd
* DOCSUP-2806: Add meta intro. * DOCSUP-2806: Update meta intro. * DOCSUP-2806: Fix meta. * DOCSUP-2806: Add quotes for meta headers. * DOCSUP-2806: Remove quotes from meta headers. * DOCSUP-2806: Add meta headers. * DOCSUP-2806: Fix quotes in meta headers. * DOCSUP-2806: Update meta headers. * DOCSUP-2806: Fix link to nowhere in EN. * DOCSUP-2806: Fix link (settings to tune) * DOCSUP-2806: Fix links. * DOCSUP-2806:Fix links EN * DOCSUP-2806: Fix build errors. * DOCSUP-2806: Fix meta intro. * DOCSUP-2806: Fix toc_priority in examples datasets TOC. * DOCSUP-2806: Fix items order in toc. * DOCSUP-2806: Fix order in toc. * DOCSUP-2806: Fix toc order. * DOCSUP-2806: Fix order in toc. * DOCSUP-2806: Fix toc index in create * DOCSUP-2806: Fix toc order in create. Co-authored-by: romanzhukov <romanzhukov@yandex-team.ru> Co-authored-by: alexey-milovidov <milovidov@yandex-team.ru>
369 lines
8.1 KiB
Markdown
369 lines
8.1 KiB
Markdown
---
|
|
toc_priority: 16
|
|
toc_title: Star Schema Benchmark
|
|
---
|
|
|
|
# Star Schema Benchmark {#star-schema-benchmark}
|
|
|
|
Compiling dbgen:
|
|
|
|
``` bash
|
|
$ git clone git@github.com:vadimtk/ssb-dbgen.git
|
|
$ cd ssb-dbgen
|
|
$ make
|
|
```
|
|
|
|
Generating data:
|
|
|
|
!!! warning "Attention"
|
|
With `-s 100` dbgen generates 600 million rows (67 GB), while while `-s 1000` it generates 6 billion rows (which takes a lot of time)
|
|
|
|
``` bash
|
|
$ ./dbgen -s 1000 -T c
|
|
$ ./dbgen -s 1000 -T l
|
|
$ ./dbgen -s 1000 -T p
|
|
$ ./dbgen -s 1000 -T s
|
|
$ ./dbgen -s 1000 -T d
|
|
```
|
|
|
|
Creating tables in ClickHouse:
|
|
|
|
``` sql
|
|
CREATE TABLE customer
|
|
(
|
|
C_CUSTKEY UInt32,
|
|
C_NAME String,
|
|
C_ADDRESS String,
|
|
C_CITY LowCardinality(String),
|
|
C_NATION LowCardinality(String),
|
|
C_REGION LowCardinality(String),
|
|
C_PHONE String,
|
|
C_MKTSEGMENT LowCardinality(String)
|
|
)
|
|
ENGINE = MergeTree ORDER BY (C_CUSTKEY);
|
|
|
|
CREATE TABLE lineorder
|
|
(
|
|
LO_ORDERKEY UInt32,
|
|
LO_LINENUMBER UInt8,
|
|
LO_CUSTKEY UInt32,
|
|
LO_PARTKEY UInt32,
|
|
LO_SUPPKEY UInt32,
|
|
LO_ORDERDATE Date,
|
|
LO_ORDERPRIORITY LowCardinality(String),
|
|
LO_SHIPPRIORITY UInt8,
|
|
LO_QUANTITY UInt8,
|
|
LO_EXTENDEDPRICE UInt32,
|
|
LO_ORDTOTALPRICE UInt32,
|
|
LO_DISCOUNT UInt8,
|
|
LO_REVENUE UInt32,
|
|
LO_SUPPLYCOST UInt32,
|
|
LO_TAX UInt8,
|
|
LO_COMMITDATE Date,
|
|
LO_SHIPMODE LowCardinality(String)
|
|
)
|
|
ENGINE = MergeTree PARTITION BY toYear(LO_ORDERDATE) ORDER BY (LO_ORDERDATE, LO_ORDERKEY);
|
|
|
|
CREATE TABLE part
|
|
(
|
|
P_PARTKEY UInt32,
|
|
P_NAME String,
|
|
P_MFGR LowCardinality(String),
|
|
P_CATEGORY LowCardinality(String),
|
|
P_BRAND LowCardinality(String),
|
|
P_COLOR LowCardinality(String),
|
|
P_TYPE LowCardinality(String),
|
|
P_SIZE UInt8,
|
|
P_CONTAINER LowCardinality(String)
|
|
)
|
|
ENGINE = MergeTree ORDER BY P_PARTKEY;
|
|
|
|
CREATE TABLE supplier
|
|
(
|
|
S_SUPPKEY UInt32,
|
|
S_NAME String,
|
|
S_ADDRESS String,
|
|
S_CITY LowCardinality(String),
|
|
S_NATION LowCardinality(String),
|
|
S_REGION LowCardinality(String),
|
|
S_PHONE String
|
|
)
|
|
ENGINE = MergeTree ORDER BY S_SUPPKEY;
|
|
```
|
|
|
|
Inserting data:
|
|
|
|
``` bash
|
|
$ clickhouse-client --query "INSERT INTO customer FORMAT CSV" < customer.tbl
|
|
$ clickhouse-client --query "INSERT INTO part FORMAT CSV" < part.tbl
|
|
$ clickhouse-client --query "INSERT INTO supplier FORMAT CSV" < supplier.tbl
|
|
$ clickhouse-client --query "INSERT INTO lineorder FORMAT CSV" < lineorder.tbl
|
|
```
|
|
|
|
Converting “star schema” to denormalized “flat schema”:
|
|
|
|
``` sql
|
|
SET max_memory_usage = 20000000000;
|
|
|
|
CREATE TABLE lineorder_flat
|
|
ENGINE = MergeTree
|
|
PARTITION BY toYear(LO_ORDERDATE)
|
|
ORDER BY (LO_ORDERDATE, LO_ORDERKEY) AS
|
|
SELECT
|
|
l.LO_ORDERKEY AS LO_ORDERKEY,
|
|
l.LO_LINENUMBER AS LO_LINENUMBER,
|
|
l.LO_CUSTKEY AS LO_CUSTKEY,
|
|
l.LO_PARTKEY AS LO_PARTKEY,
|
|
l.LO_SUPPKEY AS LO_SUPPKEY,
|
|
l.LO_ORDERDATE AS LO_ORDERDATE,
|
|
l.LO_ORDERPRIORITY AS LO_ORDERPRIORITY,
|
|
l.LO_SHIPPRIORITY AS LO_SHIPPRIORITY,
|
|
l.LO_QUANTITY AS LO_QUANTITY,
|
|
l.LO_EXTENDEDPRICE AS LO_EXTENDEDPRICE,
|
|
l.LO_ORDTOTALPRICE AS LO_ORDTOTALPRICE,
|
|
l.LO_DISCOUNT AS LO_DISCOUNT,
|
|
l.LO_REVENUE AS LO_REVENUE,
|
|
l.LO_SUPPLYCOST AS LO_SUPPLYCOST,
|
|
l.LO_TAX AS LO_TAX,
|
|
l.LO_COMMITDATE AS LO_COMMITDATE,
|
|
l.LO_SHIPMODE AS LO_SHIPMODE,
|
|
c.C_NAME AS C_NAME,
|
|
c.C_ADDRESS AS C_ADDRESS,
|
|
c.C_CITY AS C_CITY,
|
|
c.C_NATION AS C_NATION,
|
|
c.C_REGION AS C_REGION,
|
|
c.C_PHONE AS C_PHONE,
|
|
c.C_MKTSEGMENT AS C_MKTSEGMENT,
|
|
s.S_NAME AS S_NAME,
|
|
s.S_ADDRESS AS S_ADDRESS,
|
|
s.S_CITY AS S_CITY,
|
|
s.S_NATION AS S_NATION,
|
|
s.S_REGION AS S_REGION,
|
|
s.S_PHONE AS S_PHONE,
|
|
p.P_NAME AS P_NAME,
|
|
p.P_MFGR AS P_MFGR,
|
|
p.P_CATEGORY AS P_CATEGORY,
|
|
p.P_BRAND AS P_BRAND,
|
|
p.P_COLOR AS P_COLOR,
|
|
p.P_TYPE AS P_TYPE,
|
|
p.P_SIZE AS P_SIZE,
|
|
p.P_CONTAINER AS P_CONTAINER
|
|
FROM lineorder AS l
|
|
INNER JOIN customer AS c ON c.C_CUSTKEY = l.LO_CUSTKEY
|
|
INNER JOIN supplier AS s ON s.S_SUPPKEY = l.LO_SUPPKEY
|
|
INNER JOIN part AS p ON p.P_PARTKEY = l.LO_PARTKEY;
|
|
```
|
|
|
|
Running the queries:
|
|
|
|
Q1.1
|
|
|
|
``` sql
|
|
SELECT sum(LO_EXTENDEDPRICE * LO_DISCOUNT) AS revenue
|
|
FROM lineorder_flat
|
|
WHERE toYear(LO_ORDERDATE) = 1993 AND LO_DISCOUNT BETWEEN 1 AND 3 AND LO_QUANTITY < 25;
|
|
```
|
|
|
|
Q1.2
|
|
|
|
``` sql
|
|
SELECT sum(LO_EXTENDEDPRICE * LO_DISCOUNT) AS revenue
|
|
FROM lineorder_flat
|
|
WHERE toYYYYMM(LO_ORDERDATE) = 199401 AND LO_DISCOUNT BETWEEN 4 AND 6 AND LO_QUANTITY BETWEEN 26 AND 35;
|
|
```
|
|
|
|
Q1.3
|
|
|
|
``` sql
|
|
SELECT sum(LO_EXTENDEDPRICE * LO_DISCOUNT) AS revenue
|
|
FROM lineorder_flat
|
|
WHERE toISOWeek(LO_ORDERDATE) = 6 AND toYear(LO_ORDERDATE) = 1994
|
|
AND LO_DISCOUNT BETWEEN 5 AND 7 AND LO_QUANTITY BETWEEN 26 AND 35;
|
|
```
|
|
|
|
Q2.1
|
|
|
|
``` sql
|
|
SELECT
|
|
sum(LO_REVENUE),
|
|
toYear(LO_ORDERDATE) AS year,
|
|
P_BRAND
|
|
FROM lineorder_flat
|
|
WHERE P_CATEGORY = 'MFGR#12' AND S_REGION = 'AMERICA'
|
|
GROUP BY
|
|
year,
|
|
P_BRAND
|
|
ORDER BY
|
|
year,
|
|
P_BRAND;
|
|
```
|
|
|
|
Q2.2
|
|
|
|
``` sql
|
|
SELECT
|
|
sum(LO_REVENUE),
|
|
toYear(LO_ORDERDATE) AS year,
|
|
P_BRAND
|
|
FROM lineorder_flat
|
|
WHERE P_BRAND >= 'MFGR#2221' AND P_BRAND <= 'MFGR#2228' AND S_REGION = 'ASIA'
|
|
GROUP BY
|
|
year,
|
|
P_BRAND
|
|
ORDER BY
|
|
year,
|
|
P_BRAND;
|
|
```
|
|
|
|
Q2.3
|
|
|
|
``` sql
|
|
SELECT
|
|
sum(LO_REVENUE),
|
|
toYear(LO_ORDERDATE) AS year,
|
|
P_BRAND
|
|
FROM lineorder_flat
|
|
WHERE P_BRAND = 'MFGR#2239' AND S_REGION = 'EUROPE'
|
|
GROUP BY
|
|
year,
|
|
P_BRAND
|
|
ORDER BY
|
|
year,
|
|
P_BRAND;
|
|
```
|
|
|
|
Q3.1
|
|
|
|
``` sql
|
|
SELECT
|
|
C_NATION,
|
|
S_NATION,
|
|
toYear(LO_ORDERDATE) AS year,
|
|
sum(LO_REVENUE) AS revenue
|
|
FROM lineorder_flat
|
|
WHERE C_REGION = 'ASIA' AND S_REGION = 'ASIA' AND year >= 1992 AND year <= 1997
|
|
GROUP BY
|
|
C_NATION,
|
|
S_NATION,
|
|
year
|
|
ORDER BY
|
|
year ASC,
|
|
revenue DESC;
|
|
```
|
|
|
|
Q3.2
|
|
|
|
``` sql
|
|
SELECT
|
|
C_CITY,
|
|
S_CITY,
|
|
toYear(LO_ORDERDATE) AS year,
|
|
sum(LO_REVENUE) AS revenue
|
|
FROM lineorder_flat
|
|
WHERE C_NATION = 'UNITED STATES' AND S_NATION = 'UNITED STATES' AND year >= 1992 AND year <= 1997
|
|
GROUP BY
|
|
C_CITY,
|
|
S_CITY,
|
|
year
|
|
ORDER BY
|
|
year ASC,
|
|
revenue DESC;
|
|
```
|
|
|
|
Q3.3
|
|
|
|
``` sql
|
|
SELECT
|
|
C_CITY,
|
|
S_CITY,
|
|
toYear(LO_ORDERDATE) AS year,
|
|
sum(LO_REVENUE) AS revenue
|
|
FROM lineorder_flat
|
|
WHERE (C_CITY = 'UNITED KI1' OR C_CITY = 'UNITED KI5') AND (S_CITY = 'UNITED KI1' OR S_CITY = 'UNITED KI5') AND year >= 1992 AND year <= 1997
|
|
GROUP BY
|
|
C_CITY,
|
|
S_CITY,
|
|
year
|
|
ORDER BY
|
|
year ASC,
|
|
revenue DESC;
|
|
```
|
|
|
|
Q3.4
|
|
|
|
``` sql
|
|
SELECT
|
|
C_CITY,
|
|
S_CITY,
|
|
toYear(LO_ORDERDATE) AS year,
|
|
sum(LO_REVENUE) AS revenue
|
|
FROM lineorder_flat
|
|
WHERE (C_CITY = 'UNITED KI1' OR C_CITY = 'UNITED KI5') AND (S_CITY = 'UNITED KI1' OR S_CITY = 'UNITED KI5') AND toYYYYMM(LO_ORDERDATE) = 199712
|
|
GROUP BY
|
|
C_CITY,
|
|
S_CITY,
|
|
year
|
|
ORDER BY
|
|
year ASC,
|
|
revenue DESC;
|
|
```
|
|
|
|
Q4.1
|
|
|
|
``` sql
|
|
SELECT
|
|
toYear(LO_ORDERDATE) AS year,
|
|
C_NATION,
|
|
sum(LO_REVENUE - LO_SUPPLYCOST) AS profit
|
|
FROM lineorder_flat
|
|
WHERE C_REGION = 'AMERICA' AND S_REGION = 'AMERICA' AND (P_MFGR = 'MFGR#1' OR P_MFGR = 'MFGR#2')
|
|
GROUP BY
|
|
year,
|
|
C_NATION
|
|
ORDER BY
|
|
year ASC,
|
|
C_NATION ASC;
|
|
```
|
|
|
|
Q4.2
|
|
|
|
``` sql
|
|
SELECT
|
|
toYear(LO_ORDERDATE) AS year,
|
|
S_NATION,
|
|
P_CATEGORY,
|
|
sum(LO_REVENUE - LO_SUPPLYCOST) AS profit
|
|
FROM lineorder_flat
|
|
WHERE C_REGION = 'AMERICA' AND S_REGION = 'AMERICA' AND (year = 1997 OR year = 1998) AND (P_MFGR = 'MFGR#1' OR P_MFGR = 'MFGR#2')
|
|
GROUP BY
|
|
year,
|
|
S_NATION,
|
|
P_CATEGORY
|
|
ORDER BY
|
|
year ASC,
|
|
S_NATION ASC,
|
|
P_CATEGORY ASC;
|
|
```
|
|
|
|
Q4.3
|
|
|
|
``` sql
|
|
SELECT
|
|
toYear(LO_ORDERDATE) AS year,
|
|
S_CITY,
|
|
P_BRAND,
|
|
sum(LO_REVENUE - LO_SUPPLYCOST) AS profit
|
|
FROM lineorder_flat
|
|
WHERE S_NATION = 'UNITED STATES' AND (year = 1997 OR year = 1998) AND P_CATEGORY = 'MFGR#14'
|
|
GROUP BY
|
|
year,
|
|
S_CITY,
|
|
P_BRAND
|
|
ORDER BY
|
|
year ASC,
|
|
S_CITY ASC,
|
|
P_BRAND ASC;
|
|
```
|
|
|
|
[Original article](https://clickhouse.tech/docs/en/getting_started/example_datasets/star_schema/) <!--hide-->
|