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

Commit 683d8ab

Browse files
committed
schema "security" tightened, typos fixed
1 parent 20e6240 commit 683d8ab

16 files changed

+220
-75
lines changed

00_create_database.sql

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

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-
*/
76

87
CREATE DATABASE pg_features_demo;
98

01_create_role.sql

Lines changed: 14 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,21 @@
11
-- Create a role (a.k.a: user, login, group) that is allowed to log in.
22
-- 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.
33
-- But if this is not wanted, per DB connections can be set up with "REVOKE/GRANT CONNECT ON DATABASE"
4-
CREATE ROLE demorole WITH LOGIN;
4+
5+
CREATE ROLE demorole WITH LOGIN; -- create a normal(unprivileged) user
56

67
-- Will later be set up to only allow selecting data
78
CREATE ROLE demorole_ro WITH LOGIN;
89

9-
-- TODO Super, password, mention other auth methods
10+
-- turning a normal user to superuser
11+
ALTER ROLE demorole SUPERUSER;
12+
ALTER ROLE demorole NOSUPERUSER;
13+
14+
-- one can also specify passwords from command line but that's not recommended, if needed then only in md5 form
15+
-- recommended way is to use the psql "\password" command.
16+
17+
ALTER ROLE demorole_ro PASSWORD 'mypass';
18+
-- md5 format, hash generated with "select md5('mypassdemorole_ro')"
19+
ALTER ROLE demorole_ro PASSWORD 'md50aa307ba3b035a4c77e7417a75bf71af';
20+
21+
ALTER DATABASE pg_features_demo OWNER TO demorole;

02_create_schema.sql

Lines changed: 14 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -1,25 +1,32 @@
1+
RESET ROLE;
12
/*
23
Schemas in Postgres are basically "namespaces", allowing tables with same names within one DB, if schema names differ.
34
By default there is always one "public" schema pre-created with every database, but for bigger applications it is usually
45
preferable to create more schemas to logically group business functionality: e.g. customer_data, product_data.
56
67
Hierarchy of objects is thus such: Cluster -> Database -> Schema -> Table
78
*/
8-
CREATE SCHEMA IF NOT EXISTS banking_demo AUTHORIZATION demorole;
9+
CREATE SCHEMA IF NOT EXISTS banking AUTHORIZATION demorole; -- here we create a schema for our demo banking app
910

1011
/*
1112
When creating schemas, one also usually should define according access privileges.
1213
"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.
14+
NB! If you grant something to "public" role (an internal synonym for "all users"), then every user has this grant.
1515
*/
16-
GRANT USAGE ON SCHEMA banking_demo TO public;
17-
16+
GRANT USAGE ON SCHEMA banking TO demorole_ro; -- keeping things tight here
17+
-- now only demorole (owner) and demorole_ro have access
1818

1919
/*
2020
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
21+
Here for example we declare that for all tables we create in our banking schema, system will automatically grant
2222
read rights for the "demorole_ro" role.
2323
*/
24-
ALTER DEFAULT PRIVILEGES IN SCHEMA banking_demo
24+
SET ROLE TO demorole;
25+
26+
ALTER DEFAULT PRIVILEGES
27+
FOR ROLE demorole
28+
IN SCHEMA banking
29+
GRANT SELECT ON TABLES TO demorole_ro;
30+
ALTER DEFAULT PRIVILEGES
31+
IN SCHEMA public
2532
GRANT SELECT ON TABLES TO demorole_ro;

02_search_path.sql

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -11,12 +11,12 @@ Schemas can also be used to do sort of "API versioning" when using views or stor
1111
SELECT current_setting('search_path') AS default_search_path;
1212

1313
-- currently we need to type for example something like that:
14-
-- SELECT count(*) from banking_demo.tableX
14+
-- SELECT count(*) from banking.tableX
1515

1616
-- will become active on next login or after server settings reload
17-
ALTER DATABASE pg_features_demo SET search_path TO banking_demo, public;
17+
ALTER DATABASE pg_features_demo SET search_path TO public, banking;
1818
-- for this session also
19-
SET search_path TO banking_demo, public;
19+
SET search_path TO public, banking;
2020

21-
-- after that we can type:
21+
-- after that we can for example query tables from the "banking" schema without specifying the schema explicitly:
2222
-- SELECT count(*) from tableX

03_make_public_schema_secure.sql

Lines changed: 14 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,20 @@
11
/*
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.
2+
3+
For sensitive environments it is recommended to avoid creating object in the "public" schema or even better to secure
4+
the "public" schema like below so that people could not create tables in there and look at other peoples structures.
5+
When still working with the public schema you would also want to set up DEFAULT PRIVILEGES that your "trusted users"
6+
would still get automatic access to new object in the "public" schema.
57
*/
8+
9+
-- USAGE for schemas allows looking at structures within schemas, a prerequisite for looking at data
10+
-- additionally unprivileged users can create tables, causing IO load and danger of running out of disk space
611
REVOKE USAGE ON SCHEMA public FROM public;
712

813
-- Whitelist needed users later
914
GRANT USAGE ON SCHEMA public TO demorole;
15+
GRANT USAGE ON SCHEMA public TO demorole_ro;
16+
17+
ALTER DEFAULT PRIVILEGES
18+
IN SCHEMA public
19+
GRANT SELECT ON TABLES TO demorole_ro;
20+

04_alter_role.sql

Lines changed: 7 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,11 @@
11
-- It's possible to set global, or per user or per user/db settings. Most used such settings are search_path and statement_timeout.
22
-- Changes are effective with next login.
33

4-
ALTER ROLE demorole IN DATABASE pg_features_demo SET search_path TO demo, public;
5-
ALTER ROLE demorole_ro IN DATABASE pg_features_demo SET search_path TO demo, public;
4+
RESET ROLE;
5+
6+
ALTER ROLE demorole IN DATABASE pg_features_demo SET search_path TO public, banking;
7+
ALTER ROLE demorole_ro IN DATABASE pg_features_demo SET search_path TO public, banking;
68
ALTER ROLE demorole_ro IN DATABASE pg_features_demo SET statement_timeout TO '5s';
9+
10+
SET ROLE TO demorole;
11+

05_create_table.sql

Lines changed: 23 additions & 22 deletions
Original file line numberDiff line numberDiff line change
@@ -7,25 +7,26 @@ SET ROLE TO demorole;
77
-- CREATE TABLEs for our super-simplified banking schema. For those more familiar with Postgres you may notice the schema is
88
-- very similar to the one used by default Postgres benchmarking tool "pgbench"
99

10-
CREATE TABLE banking_demo.branch(
10+
CREATE TABLE banking.branch(
1111
branch_id int NOT NULL PRIMARY KEY, -- using just "id" for name here is not recommended, the more explicit the better for important stuff
1212
balance numeric NOT NULL DEFAULT 0
1313
);
1414

15-
CREATE TABLE banking_demo.teller(
15+
CREATE TABLE banking.teller(
1616
teller_id int NOT NULL PRIMARY KEY,
1717
branch_id int NOT NULL,
1818
balance numeric NOT NULL DEFAULT 0
1919
);
2020

21-
CREATE TABLE banking_demo.account(
21+
CREATE TABLE banking.account(
2222
account_id int NOT NULL PRIMARY KEY,
2323
branch_id int NOT NULL,
2424
teller_id int NOT NULL,
2525
balance numeric NOT NULL DEFAULT 0
2626
);
2727

28-
CREATE TABLE banking_demo.transaction_history(
28+
CREATE TABLE banking.transaction_history(
29+
id SERIAL NOT NULL,
2930
teller_id int NOT NULL,
3031
branch_id int NOT NULL,
3132
account_id int NOT NULL,
@@ -34,39 +35,39 @@ CREATE TABLE banking_demo.transaction_history(
3435
);
3536

3637
-- Generally it's also a good practice to at least minimally comment the tables and columns for complex applications
37-
COMMENT ON TABLE banking_demo.transaction_history IS 'A simple banking table';
38-
COMMENT ON COLUMN banking_demo.transaction_history.delta IS 'Change in account balance for one transaction';
38+
COMMENT ON TABLE banking.transaction_history IS 'A simple banking table';
39+
COMMENT ON COLUMN banking.transaction_history.delta IS 'Change in account balance for one transaction';
3940

4041
-- generate 1 branch, 10 tellers for branch, 10K accounts for each teller with random balances
4142

42-
INSERT INTO banking_demo.branch (branch_id)
43+
INSERT INTO banking.branch (branch_id)
4344
VALUES (1);
4445

45-
INSERT INTO banking_demo.teller (teller_id, branch_id)
46+
INSERT INTO banking.teller (teller_id, branch_id)
4647
SELECT generate_series(1, 10), 1;
4748

48-
INSERT INTO banking_demo.account (account_id, teller_id, branch_id)
49+
INSERT INTO banking.account (account_id, teller_id, branch_id)
4950
SELECT i, i % 10 + 1, 1 FROM generate_series(1, 1e5) i;
5051

5152

5253
-- Adding foreign keys and indexes
5354
-- (more correct would be to add them before inserting data but also inserts would be slower then)
5455

55-
CREATE INDEX ON banking_demo.account (teller_id);
56-
CREATE INDEX ON banking_demo.account (branch_id);
57-
CREATE INDEX ON banking_demo.transaction_history (account_id);
58-
CREATE INDEX ON banking_demo.transaction_history (teller_id);
59-
CREATE INDEX ON banking_demo.transaction_history (created_on);
56+
CREATE INDEX ON banking.account (teller_id);
57+
CREATE INDEX ON banking.account (branch_id);
58+
CREATE INDEX ON banking.transaction_history (account_id);
59+
CREATE INDEX ON banking.transaction_history (teller_id);
60+
CREATE INDEX ON banking.transaction_history (created_on);
6061

61-
ALTER TABLE banking_demo.teller ADD FOREIGN KEY (branch_id) REFERENCES banking_demo.branch;
62-
ALTER TABLE banking_demo.account ADD FOREIGN KEY (branch_id) REFERENCES banking_demo.branch;
63-
ALTER TABLE banking_demo.account ADD FOREIGN KEY (teller_id) REFERENCES banking_demo.teller;
64-
ALTER TABLE banking_demo.transaction_history ADD FOREIGN KEY (branch_id) REFERENCES banking_demo.branch;
65-
ALTER TABLE banking_demo.transaction_history ADD FOREIGN KEY (teller_id) REFERENCES banking_demo.teller;
66-
ALTER TABLE banking_demo.transaction_history ADD FOREIGN KEY (account_id) REFERENCES banking_demo.account;
62+
ALTER TABLE banking.teller ADD FOREIGN KEY (branch_id) REFERENCES banking.branch;
63+
ALTER TABLE banking.account ADD FOREIGN KEY (branch_id) REFERENCES banking.branch;
64+
ALTER TABLE banking.account ADD FOREIGN KEY (teller_id) REFERENCES banking.teller;
65+
ALTER TABLE banking.transaction_history ADD FOREIGN KEY (branch_id) REFERENCES banking.branch;
66+
ALTER TABLE banking.transaction_history ADD FOREIGN KEY (teller_id) REFERENCES banking.teller;
67+
ALTER TABLE banking.transaction_history ADD FOREIGN KEY (account_id) REFERENCES banking.account;
6768

6869

6970
-- Also when adding/changing a lot of row that will be used immediately it is benefical to explicitly force gathering
7071
-- of column statistics with ANALYZE
71-
ANALYZE banking_demo.teller;
72-
ANALYZE banking_demo.account;
72+
ANALYZE banking.teller;
73+
ANALYZE banking.account;

06_create_table_options.sql

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -8,12 +8,12 @@ Other types of tables are:
88
2) "unlogged" tables - such tables are not WAL-logged thus a lot faster to work with. Downside is that they're emptied after a crash.
99
*/
1010

11-
-- create a temporary copy of banking_demo.teller
11+
-- create a temporary copy of banking.teller
1212
-- NB! Note that you cannot specify a schema for temp tables
13-
CREATE TEMP TABLE teller_temp(LIKE banking_demo.teller EXCLUDING INDEXES);
13+
CREATE TEMP TABLE teller_temp(LIKE banking.teller EXCLUDING INDEXES);
1414

1515
-- could also "auto create" a table from select (no indexes, FKs, checks, etc are transferred)
16-
CREATE TEMP TABLE teller_temp_2 AS SELECT * FROM banking_demo.teller WHERE false;
16+
CREATE TEMP TABLE teller_temp_2 AS SELECT * FROM banking.teller WHERE false;
1717

1818
-- unlogged tables are a good option for staging tables that get a lot of updates and can be re-initialized quickly from input data
19-
CREATE UNLOGGED TABLE banking_demo.staging_data AS SELECT * FROM banking_demo.account;
19+
CREATE UNLOGGED TABLE banking.staging_data AS SELECT * FROM banking.account;

07_alter_table.sql

Lines changed: 5 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -13,17 +13,17 @@ ALTER TABLE is mostly commonly used to:
1313
-- adding a new column
1414
-- note that here we also demonstrate that changing the structure can be performed transactionally!! (unlike in Oracle for example)
1515
BEGIN;
16-
ALTER TABLE account_unlogged ADD COLUMN extra_info TEXT;
17-
ALTER TABLE account_unlogged ALTER COLUMN extra_info SET DEFAULT 'hello';
16+
ALTER TABLE staging_data ADD COLUMN extra_info TEXT;
17+
ALTER TABLE staging_data ALTER COLUMN extra_info SET DEFAULT 'hello';
1818
COMMIT;
1919
-- also note that for big tables on busy DBs the above 2-step form is much preferred over below form as it won't re-write the whole table:
2020
-- ALTER TABLE account_unlogged ADD COLUMN extra_info TEXT DEFAULT 'hello';
2121

2222
-- adding a simple check constraint
23-
ALTER TABLE account_unlogged ADD CONSTRAINT CHECK my_check CHECK (account_id > 0);
23+
ALTER TABLE staging_data ADD CONSTRAINT my_check CHECK (account_id > 0);
2424

2525
-- change column data type. NB! mostly it means a full table re-write so be wary.
26-
ALTER TABLE account_unlogged ALTER COLUMN extra_info TYPE varchar(500);
26+
ALTER TABLE staging_data ALTER COLUMN extra_info TYPE varchar(500);
2727

2828

2929
/*
@@ -32,4 +32,4 @@ It tells Postgres to fill up tables only to specified percentage, so that future
3232
have a chance to be performed "in line" (called HOT-updates). Some "terms and conditions" apply but for certain usecases (a lot of
3333
updates on un-indexed columns) huge boosts are possible. Fillfactor can be also specified similarily when creating the table.
3434
*/
35-
ALTER TABLE account_unlogged SET (FILLFACTOR=80);
35+
ALTER TABLE staging_data SET (FILLFACTOR=80);

09_data_type_showcase.sql

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
CREATE TABLE main_datatypes (
1+
CREATE TABLE public.main_datatypes (
22
/* serials aka sequences */
33
id bigserial PRIMARY KEY, -- serial/bigserial corresponds to int4/int8 and will just auto-attach a DEFAULT sequence
44

@@ -25,8 +25,8 @@ CREATE TABLE main_datatypes (
2525
/* typical auditing fields to track changes of important data*/
2626
created_by text NOT NULL DEFAULT current_user,
2727
created_on timestamptz NOT NULL DEFAULT now(),
28-
last_modified_by text -- would need a trigger to ensure it's always updated when changing data
29-
last_modified_on timestamptz, -- would need a trigger to ensure it's always updated when changing data
28+
last_modified_by text, -- would need a trigger to ensure it's always updated when changing data
29+
last_modified_on timestamptz -- would need a trigger to ensure it's always updated when changing data
3030
);
3131

3232

0 commit comments

Comments
 (0)