Skip to content
This repository was archived by the owner on Oct 11, 2024. It is now read-only.

Commit a898afa

Browse files
committed
restructuring
1 parent 5a45e4a commit a898afa

18 files changed

+245
-37
lines changed

00_create_database.sql

Lines changed: 17 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,21 @@
1+
DROP DATABASE IF EXISTS pg_features_demo;
2+
3+
/*
4+
-- NB! Dropping databases will fail if there are sessions connected to it. In such cases connected users can be for exmple "killed" with:
5+
SELECT count(*) AS sessions_killed FROM (SELECT pg_terminate_backend(pid) FROM pg_stat_activity WHERE datname = 'pg_features_demo') a;
6+
*/
7+
18
CREATE DATABASE pg_features_demo;
29

10+
/* Background info:
11+
12+
One Postgres cluster (called also a host or an instance, distinguished by a unique network IP+port pair) can have X amount of databases
13+
that only share user accounts (roles).
14+
15+
In case of multiple environments (enterprize scenario) it is highly recommended to include the environment name into the DB name, to
16+
minimize chances of executing things on the wrong DB - e.g. dev_app1_db, prod_app1_db.
17+
18+
*/
19+
320
-- assuming "psql" as execution environment here
421
\c pg_features_demo

01_create_role.sql

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,3 +1,9 @@
1+
-- Create a role (a.k.a: user, login, group) that is allowed to log in.
2+
-- NB! By default roles are allowed to connect to all databases of a cluster. This does not mean that they can automatically access tables though.
3+
-- But if this is not wanted, per DB connections can be set up with "REVOKE/GRANT CONNECT ON DATABASE"
14
CREATE ROLE demorole WITH LOGIN;
25

6+
-- Will later be set up to only allow selecting data
37
CREATE ROLE demorole_ro WITH LOGIN;
8+
9+
-- TODO Super, password, mention other auth methods

02_create_schema.sql

Lines changed: 22 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -1,8 +1,25 @@
1-
CREATE SCHEMA IF NOT EXISTS demo AUTHORIZATION demorole;
1+
/*
2+
Schemas in Postgres are basically "namespaces", allowing tables with same names within one DB, if schema names differ.
3+
By default there is always one "public" schema pre-created with every database, but for bigger applications it is usually
4+
preferable to create more schemas to logically group business functionality: e.g. customer_data, product_data.
5+
6+
Hierarchy of objects is thus such: Cluster -> Database -> Schema -> Table
7+
*/
8+
CREATE SCHEMA IF NOT EXISTS banking_demo AUTHORIZATION demorole;
29

3-
-- "usage" for schemas allows looking at structures within schemas
4-
-- "public" means all users
5-
GRANT USAGE ON SCHEMA demo TO public;
10+
/*
11+
When creating schemas, one also usually should define according access privileges.
12+
"USAGE" privilege for schemas is a privilege allowing looking at structures within schemas.
13+
Here we also introduce the "public" role, meaning an internal synonym for "all users" - this if you grant some rights to
14+
"public", every user has it.
15+
*/
16+
GRANT USAGE ON SCHEMA banking_demo TO public;
617

7-
ALTER DEFAULT PRIVILEGES IN SCHEMA demo
18+
19+
/*
20+
Postgres has the feature of DEFAULT PRIVILEGES that can be used to easily maintain very granular privilege systems.
21+
Here for example we declare that for all tables we create in our banking_demo schema, system will automatically grant
22+
read rights for the "demorole_ro" role.
23+
*/
24+
ALTER DEFAULT PRIVILEGES IN SCHEMA banking_demo
825
GRANT SELECT ON TABLES TO demorole_ro;

02_search_path.sql

Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,22 @@
1+
/*
2+
3+
Important concept tied to schemas is "search_path". Basically it's a priority list of schemas,
4+
used to look for objects when the schema name is not specified by user. Can be set by all users in their session,
5+
but when using multiple schemas it usually makes sense to set it DB-wide to decrease amount of typing.
6+
Schemas can also be used to do sort of "API versioning" when using views or stored procedures.
7+
8+
*/
9+
10+
-- default search path
11+
SELECT current_setting('search_path') AS default_search_path;
12+
13+
-- currently we need to type for example something like that:
14+
-- SELECT count(*) from banking_demo.tableX
15+
16+
-- will become active on next login or after server settings reload
17+
ALTER DATABASE pg_features_demo SET search_path TO banking_demo, public;
18+
-- for this session also
19+
SET search_path TO banking_demo, public;
20+
21+
-- after that we can type:
22+
-- SELECT count(*) from tableX

03_make_public_schema_secure.sql

Lines changed: 6 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,9 @@
1-
-- "usage" for schemas allows looking at structures within schemas
2-
-- avoid usage of "public" schema or better revoke "public" access for sensitive environments
1+
/*
2+
"USAGE" for schemas allows looking at structures within schemas.
3+
Thus for sensitive environments it is recommended to avoid creating object in the "public" schema (namespace) or to
4+
revoke "public" (all users) access like below.
5+
*/
36
REVOKE USAGE ON SCHEMA public FROM public;
47

5-
-- whitelist needed users
8+
-- Whitelist needed users later
69
GRANT USAGE ON SCHEMA public TO demorole;

04_alter_role.sql

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,6 @@
1-
-- effective with next login
1+
-- It's possible to set global, or per user or per user/db settings. Most used such settings are search_path and statement_timeout.
2+
-- Changes are effective with next login.
3+
24
ALTER ROLE demorole IN DATABASE pg_features_demo SET search_path TO demo, public;
35
ALTER ROLE demorole_ro IN DATABASE pg_features_demo SET search_path TO demo, public;
46
ALTER ROLE demorole_ro IN DATABASE pg_features_demo SET statement_timeout TO '5s';

05_create_table.sql

Lines changed: 61 additions & 17 deletions
Original file line numberDiff line numberDiff line change
@@ -1,26 +1,70 @@
11
-- 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".
24
SET ROLE TO demorole;
35

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()
1134
);
1235

13-
COMMENT ON TABLE t_demo IS 'a simple table';
14-
COMMENT ON COLUMN t_demo.data IS 'JSONB is designed for NoSQL';
1536

16-
INSERT INTO t_demo (data, department)
17-
VALUES ('{"user_id": 1, "order_items": [{"item_id":3, "code": "EAS123"}]}', 'sales');
1837

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;
2165

22-
-- index everything
23-
CREATE INDEX ON t_demo USING gin (data jsonb_path_ops);
2466

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;

06_create_table_like.sql

Lines changed: 0 additions & 8 deletions
This file was deleted.

06_create_table_options.sql

Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
/*
2+
Other ways of creating tables are:
3+
1) using LIKE to use an existing table as a templates and selecting (or leaving out) some constraints/checks/indexes
4+
2) create table as select ...
5+
*/
6+
7+
-- create a copy of
8+
CREATE TABLE temp (LIKE t_demo EXCLUDING INDEXES);
9+
10+
-- could also do:
11+
-- create table t_demo_log as select * from t_demo where false;
12+
13+
14+
/*
15+
Other types of tables are:
16+
1) temporary tables
17+
2) "unlogged" tables
18+
*/
19+
20+
-- temporary tables are not persistent and visible only in that session that created them
21+
CREATE TEMP TABLE t (LIKE t_demo);
22+
23+
-- unlogged tables are not WAL-logged (emptied after a crash) thus a lot faster to work with
24+
CREATE UNLOGGED TABLE t_data_staging (LIKE t_demo);
25+

07_alter_table.sql

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
/*
2+
Another significant performance tweaking option for tables is the FILLFACTOR parameter.
3+
It tells Postgres to fill up tables only to specified percentage, so that future row updates would
4+
have a chance to be performed "in line". Some "terms and conditions" apply but for certain usecases huge boosts are possible.
5+
*/
6+
ALTER TABLE

0 commit comments

Comments
 (0)