|
| 1 | +1. download tpch-tools |
| 2 | + from [official website](https://www.tpc.org/TPC_Documents_Current_Versions/download_programs/tools-download-request5.asp?bm_type=TPC-H&bm_vers=3.0.1&mode=CURRENT-ONLY) |
| 3 | +2. unzip the file and change dir to dbgen |
| 4 | +3. fill the `makefile.suite` and rename it to `Makefile`. the run `make` to build the executable file. (Note that if you |
| 5 | + work on |
| 6 | + MacOS, you need to change `import malloc.h` to `import stdlib.h` in file `varsub.c` and `bm_utils.c`) |
| 7 | +4. run `dbgen` like this `./dbgen -vf -s 1`, and the you will find `.tbl` files in the current dir. |
| 8 | +5. Process the obtained .tbl file into csv format for subsequent storage into sqllite. You can use the following script. |
| 9 | + |
| 10 | +```sql |
| 11 | +CREATE TABLE nation ( |
| 12 | + nationkey INTEGER PRIMARY KEY, |
| 13 | + name TEXT NOT NULL, |
| 14 | + regionkey INTEGER NOT NULL, |
| 15 | + comment TEXT |
| 16 | +); |
| 17 | + |
| 18 | +CREATE TABLE region ( |
| 19 | + regionkey INTEGER PRIMARY KEY, |
| 20 | + name TEXT NOT NULL, |
| 21 | + comment TEXT |
| 22 | +); |
| 23 | + |
| 24 | +CREATE TABLE part ( |
| 25 | + partkey INTEGER PRIMARY KEY, |
| 26 | + name TEXT NOT NULL, |
| 27 | + mfgr TEXT NOT NULL, |
| 28 | + brand TEXT NOT NULL, |
| 29 | + type TEXT NOT NULL, |
| 30 | + size INTEGER NOT NULL, |
| 31 | + container TEXT NOT NULL, |
| 32 | + retailprice REAL NOT NULL, |
| 33 | + comment TEXT NOT NULL |
| 34 | +); |
| 35 | + |
| 36 | +CREATE TABLE supplier ( |
| 37 | + suppkey INTEGER PRIMARY KEY, |
| 38 | + name TEXT NOT NULL, |
| 39 | + address TEXT NOT NULL, |
| 40 | + nationkey INTEGER NOT NULL, |
| 41 | + phone TEXT NOT NULL, |
| 42 | + acctbal REAL NOT NULL, |
| 43 | + comment TEXT NOT NULL |
| 44 | +); |
| 45 | + |
| 46 | +CREATE TABLE partsupp ( |
| 47 | + partkey INTEGER NOT NULL, |
| 48 | + suppkey INTEGER NOT NULL, |
| 49 | + availqty INTEGER NOT NULL, |
| 50 | + supplycost REAL NOT NULL, |
| 51 | + comment TEXT NOT NULL, |
| 52 | + PRIMARY KEY (partkey, suppkey) |
| 53 | +); |
| 54 | + |
| 55 | +CREATE TABLE customer ( |
| 56 | + custkey INTEGER PRIMARY KEY, |
| 57 | + name TEXT NOT NULL, |
| 58 | + address TEXT NOT NULL, |
| 59 | + nationkey INTEGER NOT NULL, |
| 60 | + phone TEXT NOT NULL, |
| 61 | + acctbal REAL NOT NULL, |
| 62 | + mktsegment TEXT NOT NULL, |
| 63 | + comment TEXT NOT NULL |
| 64 | +); |
| 65 | + |
| 66 | +CREATE TABLE orders ( |
| 67 | + orderkey INTEGER PRIMARY KEY, |
| 68 | + custkey INTEGER NOT NULL, |
| 69 | + orderstatus TEXT NOT NULL, |
| 70 | + totalprice REAL NOT NULL, |
| 71 | + orderdate TEXT NOT NULL, |
| 72 | + orderpriority TEXT NOT NULL, |
| 73 | + clerk TEXT NOT NULL, |
| 74 | + shippriority INTEGER NOT NULL, |
| 75 | + comment TEXT NOT NULL |
| 76 | +); |
| 77 | + |
| 78 | +CREATE TABLE lineitem ( |
| 79 | + orderkey INTEGER NOT NULL, |
| 80 | + partkey INTEGER NOT NULL, |
| 81 | + suppkey INTEGER NOT NULL, |
| 82 | + linenumber INTEGER NOT NULL, |
| 83 | + quantity REAL NOT NULL, |
| 84 | + extendedprice REAL NOT NULL, |
| 85 | + discount REAL NOT NULL, |
| 86 | + tax REAL NOT NULL, |
| 87 | + returnflag TEXT NOT NULL, |
| 88 | + linestatus TEXT NOT NULL, |
| 89 | + shipdate TEXT NOT NULL, |
| 90 | + commitdate TEXT NOT NULL, |
| 91 | + receiptdate TEXT NOT NULL, |
| 92 | + shipinstruct TEXT NOT NULL, |
| 93 | + shipmode TEXT NOT NULL, |
| 94 | + comment TEXT NOT NULL, |
| 95 | + PRIMARY KEY (orderkey, linenumber) |
| 96 | +); |
| 97 | +``` |
| 98 | + |
| 99 | + |
| 100 | +```bash |
| 101 | +#!/bin/bash |
| 102 | +folder_path="." |
| 103 | + |
| 104 | +# hard code the headers |
| 105 | +get_header() { |
| 106 | + case "$1" in |
| 107 | + "customer") |
| 108 | + echo "custkey|name|address|nationkey|phone|acctbal|mktsegment|comment" |
| 109 | + ;; |
| 110 | + "lineitem") |
| 111 | + echo "orderkey|partkey|suppkey|linenumber|quantity|extendedprice|discount|tax|returnflag|linestatus|shipdate|commitdate|receiptdate|shipinstruct|shipmode|comment" |
| 112 | + ;; |
| 113 | + "nation") |
| 114 | + echo "nationkey|name|regionkey|comment" |
| 115 | + ;; |
| 116 | + "orders") |
| 117 | + echo "orderkey|custkey|orderstatus|totalprice|orderdate|orderpriority|clerk|shippriority|comment" |
| 118 | + ;; |
| 119 | + "part") |
| 120 | + echo "partkey|name|mfgr|brand|type|size|container|retailprice|comment" |
| 121 | + ;; |
| 122 | + "partsupp") |
| 123 | + echo "partkey|suppkey|availqty|supplycost|comment" |
| 124 | + ;; |
| 125 | + "region") |
| 126 | + echo "regionkey|name|comment" |
| 127 | + ;; |
| 128 | + "supplier") |
| 129 | + echo "suppkey|name|address|nationkey|phone|acctbal|comment" |
| 130 | + ;; |
| 131 | + *) |
| 132 | + echo "" |
| 133 | + ;; |
| 134 | + esac |
| 135 | +} |
| 136 | + |
| 137 | +for file in customer.tbl lineitem.tbl nation.tbl orders.tbl part.tbl partsupp.tbl region.tbl supplier.tbl; do |
| 138 | + table_name="${file%.*}" |
| 139 | + header=$(get_header "$table_name") |
| 140 | + |
| 141 | + if [ -n "$header" ]; then |
| 142 | + tmp_file=$(mktemp "${file}.tmp.XXXXXX") |
| 143 | + echo "$header" > "$tmp_file" |
| 144 | + sed 's/|$//' "$file" >> "$tmp_file" |
| 145 | + mv "$tmp_file" "$file" |
| 146 | + else |
| 147 | + echo "cannot found $table_name, skip $file" |
| 148 | + fi |
| 149 | +done |
| 150 | + |
| 151 | +```g |
| 152 | +
|
| 153 | +6. load the data into the table. you can use follow scripts. |
| 154 | +
|
| 155 | +```sql |
| 156 | +.mode csv |
| 157 | +.separator | |
| 158 | +.import customer.tbl customer |
| 159 | +.import lineitem.tbl lineitem |
| 160 | +.import nation.tbl nation |
| 161 | +.import orders.tbl orders |
| 162 | +.import part.tbl part |
| 163 | +.import partsupp.tbl partsupp |
| 164 | +.import region.tbl region |
| 165 | +.import supplier.tbl supplier |
| 166 | +``` |
0 commit comments