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

Commit f743117

Browse files
committed
Partitioning - add multi-level partitioning example
1 parent 2215f7e commit f743117

File tree

1 file changed

+56
-0
lines changed

1 file changed

+56
-0
lines changed
Lines changed: 56 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,56 @@
1+
\c pg_features_demo
2+
3+
/*
4+
5+
As already mentioned, one can also mix different partitioning methods or even use the same method given different columns,
6+
but mostly only 2 different methods are combined with LIST + RANGE or HASH + RANGE being usually the most useful ones -
7+
for example "client" + time, meaning for each client or customer we keep action history of some months and then drop the
8+
old sub-partitions. Below a sample from monitoring domain, borrowed from our pgwatch2 monitoring tool, with the differenece
9+
that there actually the sub-partitions are managed automatically by the metric collector daemon and not created per hand.
10+
11+
FYI - with older Postgres versions it was not really recommended to "overdo" witch such more complex multi-level approaches,
12+
but as of v12 one can have many levels together with thousands of sub-partitions given SQL access specifies also all these
13+
conditions.
14+
15+
*/
16+
17+
-- LIST + RANGE sample
18+
19+
-- when lots of sub-partitions can be forseen then it's a good idea to move them into a separate schema
20+
CREATE SCHEMA subpartitions AUTHORIZATION demorole;
21+
22+
SET ROLE TO demorole;
23+
24+
-- used to "instantiate" separate metric definitions
25+
CREATE TABLE metrics_template (
26+
time timestamptz NOT NULL DEFAULT now(),
27+
dbname text NOT NULL,
28+
data jsonb NOT NULL,
29+
tag_data jsonb, -- indexed "columns"
30+
CHECK (false)
31+
);
32+
33+
CREATE INDEX ON metrics_template USING brin (time);
34+
CREATE INDEX ON metrics_template USING gin (tag_data, time) WHERE tag_data NOTNULL;
35+
36+
/*
37+
Something like below will be done by the pgwatch2 gatherer automatically when user activates some metric 'mymetric' for
38+
a monitored database named 'mydbname'
39+
*/
40+
41+
CREATE TABLE "mymetric"
42+
(LIKE metrics_template)
43+
PARTITION BY LIST (dbname);
44+
45+
CREATE TABLE subpartitions."mymetric_mydbname"
46+
PARTITION OF "mymetric"
47+
FOR VALUES IN ('mydbname') PARTITION BY RANGE (time);
48+
49+
CREATE TABLE subpartitions."mymetric_mydbname_y2020w01"
50+
PARTITION OF subpartitions."mymetric_mydbname"
51+
FOR VALUES FROM ('2020-01-01') TO ('2020-01-07');
52+
53+
INSERT INTO mymetric
54+
SELECT '2020-01-01', 'mydbname', '{"numbackends": 10}';
55+
56+
SELECT * FROM mymetric;

0 commit comments

Comments
 (0)