-
Notifications
You must be signed in to change notification settings - Fork 284
/
create_partition_id.sql
394 lines (342 loc) · 15.7 KB
/
create_partition_id.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
CREATE FUNCTION @[email protected]_partition_id(p_parent_table text, p_partition_ids bigint[], p_analyze boolean DEFAULT true, p_start_partition text DEFAULT NULL) RETURNS boolean
LANGUAGE plpgsql
AS $$
DECLARE
ex_context text;
ex_detail text;
ex_hint text;
ex_message text;
v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
v_analyze boolean := FALSE;
v_control text;
v_control_type text;
v_exists text;
v_grantees text[];
v_hasoids boolean;
v_id bigint;
v_inherit_fk boolean;
v_inherit_privileges boolean;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
v_new_search_path text;
v_old_search_path text;
v_parent_grant record;
v_parent_schema text;
v_parent_tablename text;
v_parent_tablespace text;
v_partition_interval bigint;
v_partition_created boolean := false;
v_partition_name text;
v_partition_type text;
v_publications text[];
v_revoke text;
v_row record;
v_sql text;
v_step_id bigint;
v_sub_control text;
v_sub_partition_type text;
v_sub_id_max bigint;
v_sub_id_min bigint;
v_template_table text;
v_unlogged char;
BEGIN
/*
* Function to create id partitions
*/
SELECT control
, partition_type
, partition_interval
, inherit_fk
, jobmon
, template_table
, publications
, inherit_privileges
INTO v_control
, v_partition_type
, v_partition_interval
, v_inherit_fk
, v_jobmon
, v_template_table
, v_publications
, v_inherit_privileges
FROM @[email protected]_config
WHERE parent_table = p_parent_table;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
END IF;
SELECT n.nspname, c.relname, t.spcname
INTO v_parent_schema, v_parent_tablename, v_parent_tablespace
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
LEFT OUTER JOIN pg_catalog.pg_tablespace t ON c.reltablespace = t.oid
WHERE n.nspname = split_part(p_parent_table, '.', 1)::name
AND c.relname = split_part(p_parent_table, '.', 2)::name;
SELECT general_type INTO v_control_type FROM @[email protected]_control_type(v_parent_schema, v_parent_tablename, v_control);
IF v_control_type <> 'id' THEN
RAISE EXCEPTION 'ERROR: Given parent table is not set up for id/serial partitioning';
END IF;
SELECT current_setting('search_path') INTO v_old_search_path;
IF length(v_old_search_path) > 0 THEN
v_new_search_path := '@extschema@,pg_temp,'||v_old_search_path;
ELSE
v_new_search_path := '@extschema@,pg_temp';
END IF;
IF v_jobmon THEN
SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon'::name AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
v_new_search_path := format('%s,%s',v_jobmon_schema, v_new_search_path);
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
-- Determine if this table is a child of a subpartition parent. If so, get limits of what child tables can be created based on parent suffix
SELECT sub_min::bigint, sub_max::bigint INTO v_sub_id_min, v_sub_id_max FROM @[email protected]_subpartition_limits(p_parent_table, 'id');
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job(format('PARTMAN CREATE TABLE: %s', p_parent_table));
END IF;
FOREACH v_id IN ARRAY p_partition_ids LOOP
-- Do not create the child table if it's outside the bounds of the top parent.
IF v_sub_id_min IS NOT NULL THEN
IF v_id < v_sub_id_min OR v_id >= v_sub_id_max THEN
CONTINUE;
END IF;
END IF;
v_partition_name := @[email protected]_name_length(v_parent_tablename, v_id::text, TRUE);
-- If child table already exists, skip creation
-- Have to check pg_class because if subpartitioned, table will not be in pg_tables
SELECT c.relname INTO v_exists
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = v_parent_schema::name AND c.relname = v_partition_name::name;
IF v_exists IS NOT NULL THEN
CONTINUE;
END IF;
-- Ensure analyze is run if a new partition is created. Otherwise if one isn't, will be false and analyze will be skipped
v_analyze := TRUE;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_id||' to '||(v_id + v_partition_interval)-1);
END IF;
v_sql := 'CREATE';
-- As of PG12, the unlogged/logged status of a native parent table cannot be changed via an ALTER TABLE in order to affect its children.
-- As of v4.2x, the unlogged state will be managed via the template table
SELECT relpersistence INTO v_unlogged
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name;
IF v_unlogged = 'u' and v_partition_type != 'native' THEN
v_sql := v_sql || ' UNLOGGED';
END IF;
-- Close parentheses on LIKE are below due to differing requirements of native subpartitioning
-- Same INCLUDING list is used in create_parent()
v_sql := v_sql || format(' TABLE %I.%I (LIKE %I.%I INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING STORAGE INCLUDING COMMENTS '
, v_parent_schema
, v_partition_name
, v_parent_schema
, v_parent_tablename);
IF current_setting('server_version_num')::int >= 120000 THEN
v_sql := v_sql || ' INCLUDING GENERATED ';
END IF;
SELECT sub_partition_type, sub_control INTO v_sub_partition_type, v_sub_control
FROM @[email protected]_config_sub
WHERE sub_parent = p_parent_table;
IF v_sub_partition_type = 'native' THEN
-- INCLUDING INDEXES isn't necessary for native partitioning. It isn't supported in v10 and
-- for v11+ index inheritance is automatically handled when the partition is attached
v_sql := v_sql || format(') PARTITION BY RANGE (%I) ', v_sub_control);
ELSE
v_sql := v_sql || format(' INCLUDING INDEXES) ', v_sub_control);
END IF;
IF current_setting('server_version_num')::int < 120000 THEN
-- column removed from pgclass in pg12
SELECT relhasoids INTO v_hasoids
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name;
IF v_hasoids IS TRUE THEN
v_sql := v_sql || ' WITH (OIDS)';
END IF;
END IF;
RAISE DEBUG 'create_partition_id v_sql: %', v_sql;
EXECUTE v_sql;
IF v_partition_type = 'native' THEN
IF current_setting('server_version_num')::int >= 120000 THEN
-- PG12 fixed tablespace marking on the parent of a native partition set
-- Versions older than 12 handle tablespace setting via inherit_template_properties() call below
IF v_parent_tablespace IS NOT NULL THEN
EXECUTE format('ALTER TABLE %I.%I SET TABLESPACE %I', v_parent_schema, v_partition_name, v_parent_tablespace);
END IF;
END IF;
IF v_template_table IS NOT NULL THEN
PERFORM @[email protected]_template_properties(p_parent_table, v_parent_schema, v_partition_name);
END IF;
EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I FOR VALUES FROM (%L) TO (%L)'
, v_parent_schema
, v_parent_tablename
, v_parent_schema
, v_partition_name
, v_id
, v_id + v_partition_interval);
ELSE -- non-native
IF v_parent_tablespace IS NOT NULL THEN
EXECUTE format('ALTER TABLE %I.%I SET TABLESPACE %I', v_parent_schema, v_partition_name, v_parent_tablespace);
END IF;
EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I CHECK (%I >= %s AND %I < %s )'
, v_parent_schema
, v_partition_name
, v_partition_name||'_partition_check'
, v_control
, v_id
, v_control
, v_id + v_partition_interval);
EXECUTE format('ALTER TABLE %I.%I INHERIT %I.%I', v_parent_schema, v_partition_name, v_parent_schema, v_parent_tablename);
-- Indexes cannot be created on the parent, so clustering cannot be used for native yet.
PERFORM @[email protected]_cluster(v_parent_schema, v_parent_tablename, v_parent_schema, v_partition_name);
-- Foreign keys to other tables not supported on native parent tables
IF v_inherit_fk THEN
PERFORM @[email protected]_foreign_keys(p_parent_table, v_parent_schema||'.'||v_partition_name, v_job_id);
END IF;
END IF;
-- NOTE: Privileges not automatically inherited for native. Only do so if config flag is set
IF v_partition_type != 'native' OR (v_partition_type = 'native' AND v_inherit_privileges = TRUE) THEN
PERFORM @[email protected]_privileges(v_parent_schema, v_parent_tablename, v_parent_schema, v_partition_name, v_job_id);
END IF;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
-- Will only loop once and only if sub_partitioning is actually configured
-- This seemed easier than assigning a bunch of variables then doing an IF condition
-- This column list must be kept consistent between:
-- create_parent, check_subpart_sameconfig, create_partition_id, create_partition_time, dump_partitioned_table_definition, and table definition
FOR v_row IN
SELECT sub_parent
, sub_partition_type
, sub_control
, sub_partition_interval
, sub_constraint_cols
, sub_premake
, sub_optimize_trigger
, sub_optimize_constraint
, sub_epoch
, sub_inherit_fk
, sub_retention
, sub_retention_schema
, sub_retention_keep_table
, sub_retention_keep_index
, sub_infinite_time_partitions
, sub_automatic_maintenance
, sub_jobmon
, sub_trigger_exception_handling
, sub_upsert
, sub_trigger_return_null
, sub_template_table
, sub_inherit_privileges
, sub_constraint_valid
, sub_subscription_refresh
, sub_date_trunc_interval
, sub_ignore_default_data
FROM @[email protected]_config_sub
WHERE sub_parent = p_parent_table
LOOP
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Subpartitioning '||v_partition_name);
END IF;
v_sql := format('SELECT @[email protected]_parent(
p_parent_table := %L
, p_control := %L
, p_type := %L
, p_interval := %L
, p_constraint_cols := %L
, p_premake := %L
, p_automatic_maintenance := %L
, p_inherit_fk := %L
, p_epoch := %L
, p_template_table := %L
, p_jobmon := %L
, p_start_partition := %L
, p_date_trunc_interval := %L )'
, v_parent_schema||'.'||v_partition_name
, v_row.sub_control
, v_row.sub_partition_type
, v_row.sub_partition_interval
, v_row.sub_constraint_cols
, v_row.sub_premake
, v_row.sub_automatic_maintenance
, v_row.sub_inherit_fk
, v_row.sub_epoch
, v_row.sub_template_table
, v_row.sub_jobmon
, p_start_partition
, v_row.sub_date_trunc_interval);
RAISE DEBUG 'create_partition_id (create_parent loop): %', v_sql;
EXECUTE v_sql;
UPDATE @[email protected]_config SET
retention_schema = v_row.sub_retention_schema
, retention_keep_table = v_row.sub_retention_keep_table
, retention_keep_index = v_row.sub_retention_keep_index
, optimize_trigger = v_row.sub_optimize_trigger
, optimize_constraint = v_row.sub_optimize_constraint
, infinite_time_partitions = v_row.sub_infinite_time_partitions
, trigger_exception_handling = v_row.sub_trigger_exception_handling
, upsert = v_row.sub_upsert
, inherit_privileges = v_row.sub_inherit_privileges
, trigger_return_null = v_row.sub_trigger_return_null
, constraint_valid = v_row.sub_constraint_valid
, subscription_refresh = v_row.sub_subscription_refresh
, ignore_default_data = v_row.sub_ignore_default_data
WHERE parent_table = v_parent_schema||'.'||v_partition_name;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END LOOP; -- end sub partitioning LOOP
-- Manage additonal constraints if set
PERFORM @[email protected]_constraints(p_parent_table, p_job_id := v_job_id);
IF v_publications IS NOT NULL THEN
-- NOTE: Native publication inheritance is only supported on PG14+
PERFORM @[email protected]_publications(p_parent_table, v_parent_schema, v_partition_name);
END IF;
v_partition_created := true;
END LOOP;
-- v_analyze is a local check if a new table is made.
-- p_analyze is a parameter to say whether to run the analyze at all. Used by create_parent() to avoid long exclusive lock or run_maintenence() to avoid long creation runs.
IF v_analyze AND p_analyze THEN
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Analyzing partition set: %s', p_parent_table));
END IF;
EXECUTE format('ANALYZE %I.%I', v_parent_schema, v_parent_tablename);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
IF v_partition_created = false THEN
v_step_id := add_step(v_job_id, format('No partitions created for partition set: %s', p_parent_table));
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
PERFORM close_job(v_job_id);
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_partition_created;
EXCEPTION
WHEN OTHERS THEN
GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT,
ex_context = PG_EXCEPTION_CONTEXT,
ex_detail = PG_EXCEPTION_DETAIL,
ex_hint = PG_EXCEPTION_HINT;
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NULL THEN
EXECUTE format('SELECT %I.add_job(''PARTMAN CREATE TABLE: %s'')', v_jobmon_schema, p_parent_table) INTO v_job_id;
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before job logging started'')', v_jobmon_schema, v_job_id, p_parent_table) INTO v_step_id;
ELSIF v_step_id IS NULL THEN
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before first step logged'')', v_jobmon_schema, v_job_id) INTO v_step_id;
END IF;
EXECUTE format('SELECT %I.update_step(%s, ''CRITICAL'', %L)', v_jobmon_schema, v_step_id, 'ERROR: '||coalesce(SQLERRM,'unknown'));
EXECUTE format('SELECT %I.fail_job(%s)', v_jobmon_schema, v_job_id);
END IF;
RAISE EXCEPTION '%
CONTEXT: %
DETAIL: %
HINT: %', ex_message, ex_context, ex_detail, ex_hint;
END
$$;