|
1 | 1 | -- assume "application" role |
| 2 | +-- it's a good practice to own all objects by one "application" role, so that changes could be done using the same role, |
| 3 | +-- not requiring the samewhat dangerous "superuser". |
2 | 4 | SET ROLE TO demorole; |
3 | 5 |
|
4 | | -CREATE TABLE t_demo ( |
5 | | - id serial PRIMARY KEY, |
6 | | - data jsonb, |
7 | | - department text NOT NULL, |
8 | | - created_by text NOT NULL DEFAULT current_user, |
9 | | - created_on timestamptz NOT NULL DEFAULT now(), |
10 | | - last_modified_on timestamptz |
| 6 | + |
| 7 | +-- CREATE TABLEs for our super-simplified banking schema. For those more familiar with Postgres you may notice the schema is |
| 8 | +-- very similar to the one used by default Postgres benchmarking tool "pgbench" |
| 9 | + |
| 10 | +CREATE TABLE banking_demo.branch( |
| 11 | + branch_id int NOT NULL PRIMARY KEY, -- using just "id" for name here is not recommended, the more explicit the better for important stuff |
| 12 | + balance int NOT NULL DEFAULT 0 |
| 13 | +); |
| 14 | + |
| 15 | +CREATE TABLE banking_demo.teller( |
| 16 | + teller_id int NOT NULL PRIMARY KEY, |
| 17 | + branch_id int NOT NULL, |
| 18 | + balance int NOT NULL DEFAULT 0 |
| 19 | +); |
| 20 | + |
| 21 | +CREATE TABLE banking_demo.account( |
| 22 | + account_id int NOT NULL PRIMARY KEY, |
| 23 | + branch_id int NOT NULL, |
| 24 | + teller_id int NOT NULL, |
| 25 | + balance int NOT NULL DEFAULT 0 |
| 26 | +); |
| 27 | + |
| 28 | +CREATE TABLE banking_demo.transaction_history( |
| 29 | + teller_id int NOT NULL, |
| 30 | + branch_id int NOT NULL, |
| 31 | + account_id int NOT NULL, |
| 32 | + delta int NOT NULL, |
| 33 | + created_on timestamp with time zone NOT NULL DEFAULT now() |
11 | 34 | ); |
12 | 35 |
|
13 | | -COMMENT ON TABLE t_demo IS 'a simple table'; |
14 | | -COMMENT ON COLUMN t_demo.data IS 'JSONB is designed for NoSQL'; |
15 | 36 |
|
16 | | -INSERT INTO t_demo (data, department) |
17 | | - VALUES ('{"user_id": 1, "order_items": [{"item_id":3, "code": "EAS123"}]}', 'sales'); |
18 | 37 |
|
19 | | --- index top level keys for a simple NoSQL use case. |
20 | | -CREATE INDEX CONCURRENTLY ON t_demo USING gin (data); |
| 38 | +-- generate 1 branch, 10 tellers for branch, 10K accounts for each teller with random balances |
| 39 | + |
| 40 | +INSERT INTO banking_demo.branch (branch_id) |
| 41 | + VALUES (1); |
| 42 | + |
| 43 | +INSERT INTO banking_demo.teller (teller_id, branch_id) |
| 44 | + SELECT generate_series(1, 10), 1; |
| 45 | + |
| 46 | +INSERT INTO banking_demo.account (account_id, teller_id, branch_id) |
| 47 | + SELECT i, i % 10 + 1, 1 FROM generate_series(1, 1e5) i; |
| 48 | + |
| 49 | + |
| 50 | +-- Adding foreign keys and indexes |
| 51 | +-- (more correct would be to add them before inserting data but also inserts would be slower then) |
| 52 | + |
| 53 | +CREATE INDEX ON banking_demo.account (teller_id); |
| 54 | +CREATE INDEX ON banking_demo.account (branch_id); |
| 55 | +CREATE INDEX ON banking_demo.transaction_history (account_id); |
| 56 | +CREATE INDEX ON banking_demo.transaction_history (teller_id); |
| 57 | +CREATE INDEX ON banking_demo.transaction_history (created_on); |
| 58 | + |
| 59 | +ALTER TABLE banking_demo.teller ADD FOREIGN KEY (branch_id) REFERENCES banking_demo.branch; |
| 60 | +ALTER TABLE banking_demo.account ADD FOREIGN KEY (branch_id) REFERENCES banking_demo.branch; |
| 61 | +ALTER TABLE banking_demo.account ADD FOREIGN KEY (teller_id) REFERENCES banking_demo.teller; |
| 62 | +ALTER TABLE banking_demo.transaction_history ADD FOREIGN KEY (branch_id) REFERENCES banking_demo.branch; |
| 63 | +ALTER TABLE banking_demo.transaction_history ADD FOREIGN KEY (teller_id) REFERENCES banking_demo.teller; |
| 64 | +ALTER TABLE banking_demo.transaction_history ADD FOREIGN KEY (account_id) REFERENCES banking_demo.account; |
21 | 65 |
|
22 | | --- index everything |
23 | | -CREATE INDEX ON t_demo USING gin (data jsonb_path_ops); |
24 | 66 |
|
25 | | --- Prepare for frequent changes, increase FILLFACTOR |
26 | | -ALTER TABLE t_demo SET (fillfactor=80); |
| 67 | +-- Also when adding/changing a lot of row that will be used immediately it is benefical to explicitly force gathering |
| 68 | +-- of column statistics with ANALYZE |
| 69 | +ANALYZE banking_demo.teller; |
| 70 | +ANALYZE banking_demo.account; |
0 commit comments