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

Commit 2215f7e

Browse files
committed
Partitioning samples also for HASH and LIST
1 parent c6b0ef0 commit 2215f7e

File tree

3 files changed

+71
-1
lines changed

3 files changed

+71
-1
lines changed

07_table_partitioning.sql renamed to 07_1_table_partitioning_range.sql

Lines changed: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -6,7 +6,8 @@ SET ROLE TO demorole;
66
When it can be already foreseen that a table will grow huge (100+ GB) or there is for example a "hot data" / "cold data"
77
scenario, then it makes sense to think about splitting up the table to so called partitions. And the good thing is that
88
starting from v10 there is native support for that - so that users can continue to work with the "main" or "top level"
9-
table and not care or know about the sub-partitions where data rows are actually living in.
9+
table and not care or know about the sub-partitions where data rows are actually living in. Note though that pre-creation
10+
of such sub-partitions needs to be managed by the user - but also some extensions can help with that, like 'pg_partman'.
1011
1112
Different partitioning models available:
1213

07_2_table_partitioning_hash.sql

Lines changed: 41 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,41 @@
1+
\c pg_features_demo
2+
SET ROLE TO demorole;
3+
4+
/*
5+
6+
HASH partitioning, available from v11, differentiates quite a lot from LIST and RANGE methods and in short takes care of
7+
even distribution of data for us - we just say how many sub-partitions we need (need to pre-create these as with other
8+
partitioning types) and which column will be used for calculating the hash which then will be used to choose the partition
9+
where some row will land.
10+
11+
Hash partitioning is especially suited for "key-value" or "NoSQL" use cases and it helps to increase query throughput a
12+
lot as user CRUD will be more parallel / contention free and also many background Autovacuum processes can work on the
13+
table simultaneously. Also you can use Postgres safeguarded real primary keys with hashing without problems which is problematic
14+
with other partitioning types.
15+
16+
*/
17+
18+
-- the "main" or "parent" table that users will be interacting with
19+
CREATE TABLE web_sessions (
20+
session_id uuid NOT NULL PRIMARY KEY,
21+
-- data columns ...
22+
created_on timestamptz NOT NULL DEFAULT now(),
23+
last_modified_on timestamptz,
24+
session_data jsonb
25+
26+
) PARTITION BY HASH (session_id);
27+
28+
-- partition to hold data for year 2019
29+
CREATE TABLE web_sessions_0 PARTITION OF web_sessions FOR VALUES WITH (MODULUS 4, REMAINDER 0);
30+
CREATE TABLE web_sessions_1 PARTITION OF web_sessions FOR VALUES WITH (MODULUS 4, REMAINDER 1);
31+
CREATE TABLE web_sessions_2 PARTITION OF web_sessions FOR VALUES WITH (MODULUS 4, REMAINDER 2);
32+
CREATE TABLE web_sessions_3 PARTITION OF web_sessions FOR VALUES WITH (MODULUS 4, REMAINDER 3);
33+
34+
-- we keep working with the "main" table ...
35+
INSERT INTO web_sessions(session_id, session_data)
36+
SELECT 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11', '{"auth_token": "eeshu8tiiChe4AeP4junaiyie7thewu5"}';
37+
38+
SELECT * FROM web_sessions; -- 1 row
39+
40+
-- if you want to disable implicit scanning of sub-tables one can use the ONLY keyword
41+
SELECT * FROM ONLY web_sessions; -- 0 rows

07_3_table_partitioning_list.sql

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,28 @@
1+
\c pg_features_demo
2+
SET ROLE TO demorole;
3+
4+
/*
5+
6+
LIST partitioning is probably the least used partitioning method but it gives you very explicit control over where data
7+
for some particular data sets should be stored. This can be for example used to implement some fine controlled "multi-tenant"
8+
behaviour, where some big / active customers for example have their own "table" or maybe also to implement some "hot-cold data"
9+
scenarios where orders, once processed are shifted to a separate partition for faster summary analytics. Note though that
10+
automatic moving of rows between partitions on partitioning key updates are available only from v11.
11+
12+
*/
13+
14+
-- the "main" or "parent" table that users will be interacting with
15+
CREATE TABLE orders_segmented (
16+
client_id int8 NOT NULL,
17+
order_nr int8 NOT NULL,
18+
order_date timestamptz NOT NULL DEFAULT now(),
19+
-- data columns ...
20+
UNIQUE (client_id, order_nr)
21+
) PARTITION BY LIST (client_id);
22+
23+
-- data for major customer 1
24+
CREATE TABLE orders_client_1 PARTITION OF orders_segmented FOR VALUES IN (1);
25+
-- data for major customer 2
26+
CREATE TABLE orders_client_2 PARTITION OF orders_segmented FOR VALUES IN (2);
27+
-- 1 shared partition for all the smaller "fish"
28+
CREATE TABLE orders_client_def PARTITION OF orders_segmented DEFAULT;

0 commit comments

Comments
 (0)