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 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587
|
-- No separate configuration required for setting privileges on child tables anymore. Grants config table has been dropped. Please apply the grants you need to the parent table and they will be set for all children using that. Note that unlike before, privilges that don't exist on the parent will now be revoked from all child tables.
-- create_parent() now enforces that a given parent table be schema qualified. Ensures that a custom search_path doesn't affect the wrong table by accident.
-- Removed enum custom type and replace with check function.
-- Applying of grants is now logged in pg_jobmon so if there's any issues with that step, it's clear where it failed.
/*
* Check function for config table partition types
*/
CREATE FUNCTION check_partition_type (p_type text) RETURNS boolean
LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER
AS $$
DECLARE
v_result boolean;
BEGIN
SELECT p_type IN ('time-static', 'time-dynamic', 'id-static', 'id-dynamic') INTO v_result;
RETURN v_result;
END
$$;
DROP FUNCTION @extschema@.create_parent(text, text, @extschema@.partition_type, text, int, boolean);
DROP TABLE @extschema@.part_grants;
ALTER TABLE @extschema@.part_config ADD COLUMN new_type text;
UPDATE @extschema@.part_config SET new_type = type;
ALTER TABLE @extschema@.part_config ALTER new_type SET NOT NULL;
ALTER TABLE @extschema@.part_config DROP COLUMN type;
DROP TYPE @extschema@.partition_type;
ALTER TABLE @extschema@.part_config RENAME new_type TO type;
ALTER TABLE @extschema@.part_config ADD CONSTRAINT part_config_type_check CHECK (@extschema@.check_partition_type(type));
/*
* Function to apply ownership & privileges on child tables using parent table as reference
*/
CREATE OR REPLACE FUNCTION apply_grants(p_parent_table text) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
v_child_table text;
v_count int := 0;
v_grant text;
v_grantees text[];
v_owner text;
v_owner_sql text;
v_revoke text[];
v_revoke_sql text;
v_row record;
v_sql text;
BEGIN
SELECT count(parent_table) INTO v_count FROM @extschema@.part_config WHERE parent_table = p_parent_table;
IF v_count = 0 THEN
RAISE EXCEPTION 'Given table is not managed by this extention: %', p_parent_table;
END IF;
SELECT tableowner INTO v_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
FOR v_child_table IN
SELECT inhrelid::regclass FROM pg_catalog.pg_inherits WHERE inhparent::regclass = p_parent_table::regclass ORDER BY inhrelid::regclass ASC
LOOP
v_grantees := NULL;
FOR v_row IN
SELECT array_agg(privilege_type::text) AS types, grantee
FROM information_schema.table_privileges
WHERE table_schema ||'.'|| table_name = p_parent_table
GROUP BY grantee
LOOP
EXECUTE 'GRANT '||array_to_string(v_row.types, ',')||' ON '||v_child_table||' TO '||v_row.grantee;
SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_row.types)) x;
IF v_revoke IS NOT NULL THEN
EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_child_table||' FROM '||v_row.grantee||' CASCADE';
END IF;
v_grantees := array_append(v_grantees, v_row.grantee::text);
END LOOP;
-- Revoke all privileges from roles that have none on the parent
IF v_grantees IS NOT NULL THEN
SELECT array_agg(r) INTO v_revoke FROM (
SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_child_table
EXCEPT
SELECT unnest(v_grantees)) x;
IF v_revoke IS NOT NULL THEN
EXECUTE 'REVOKE ALL ON '||v_child_table||' FROM '||array_to_string(v_revoke, ',');
END IF;
END IF;
EXECUTE 'ALTER TABLE '||v_child_table||' OWNER TO '||v_owner;
END LOOP;
END
$$;
/*
* Function to turn a table into the parent of a partition set
*/
CREATE FUNCTION create_parent(p_parent_table text, p_control text, p_type text, p_interval text, p_premake int DEFAULT 4, p_debug boolean DEFAULT false) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
v_current_id bigint;
v_datetime_string text;
v_id_interval bigint;
v_job_id bigint;
v_jobmon_schema text;
v_last_partition_name text;
v_old_search_path text;
v_partition_time timestamp[];
v_partition_id bigint[];
v_max bigint;
v_notnull boolean;
v_starting_partition_id bigint;
v_step_id bigint;
v_tablename text;
v_time_interval interval;
BEGIN
IF position('.' in p_parent_table) = 0 THEN
RAISE EXCEPTION 'Parent table must be schema qualified';
END IF;
SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = p_parent_table;
IF v_tablename IS NULL THEN
RAISE EXCEPTION 'Please create given parent table first: %', p_parent_table;
END IF;
SELECT attnotnull INTO v_notnull FROM pg_attribute WHERE attrelid = p_parent_table::regclass AND attname = p_control;
IF v_notnull = false THEN
RAISE EXCEPTION 'Control column (%) for parent table (%) must be NOT NULL', p_control, p_parent_table;
END IF;
EXECUTE 'LOCK TABLE '||p_parent_table||' IN ACCESS EXCLUSIVE MODE';
SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMAN SETUP PARENT: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Creating initial partitions on new parent table: '||p_parent_table);
END IF;
CASE
WHEN p_interval = 'yearly' THEN
v_time_interval = '1 year';
v_datetime_string := 'YYYY';
WHEN p_interval = 'quarterly' THEN
v_time_interval = '3 months';
v_datetime_string = 'YYYY"q"Q';
WHEN p_interval = 'monthly' THEN
v_time_interval = '1 month';
v_datetime_string := 'YYYY_MM';
WHEN p_interval = 'weekly' THEN
v_time_interval = '1 week';
v_datetime_string := 'IYYY"w"IW';
WHEN p_interval = 'daily' THEN
v_time_interval = '1 day';
v_datetime_string := 'YYYY_MM_DD';
WHEN p_interval = 'hourly' THEN
v_time_interval = '1 hour';
v_datetime_string := 'YYYY_MM_DD_HH24MI';
WHEN p_interval = 'half-hour' THEN
v_time_interval = '30 mins';
v_datetime_string := 'YYYY_MM_DD_HH24MI';
WHEN p_interval = 'quarter-hour' THEN
v_time_interval = '15 mins';
v_datetime_string := 'YYYY_MM_DD_HH24MI';
ELSE
IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN
v_id_interval := p_interval::bigint;
ELSE
RAISE EXCEPTION 'Invalid interval for time based partitioning: %', p_interval;
END IF;
END CASE;
IF p_type = 'time-static' OR p_type = 'time-dynamic' THEN
FOR i IN 0..p_premake LOOP
v_partition_time := array_append(v_partition_time, quote_literal(CURRENT_TIMESTAMP + (v_time_interval*i))::timestamp);
END LOOP;
INSERT INTO @extschema@.part_config (parent_table, type, part_interval, control, premake, datetime_string) VALUES
(p_parent_table, p_type, v_time_interval, p_control, p_premake, v_datetime_string);
EXECUTE 'SELECT @extschema@.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(p_control)||','
||quote_literal(v_time_interval)||','||quote_literal(v_datetime_string)||','||quote_literal(v_partition_time)||')' INTO v_last_partition_name;
-- Doing separate update because create function needs parent table in config table for apply_grants()
UPDATE @extschema@.part_config SET last_partition = v_last_partition_name WHERE parent_table = p_parent_table;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Time partitions premade: '||p_premake);
END IF;
END IF;
IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN
-- If there is already data, start partitioning with the highest current value
EXECUTE 'SELECT COALESCE(max('||p_control||')::bigint, 0) FROM '||p_parent_table||' LIMIT 1' INTO v_max;
v_starting_partition_id := v_max - (v_max % v_id_interval);
FOR i IN 0..p_premake LOOP
v_partition_id = array_append(v_partition_id, (v_id_interval*i)+v_starting_partition_id);
END LOOP;
INSERT INTO @extschema@.part_config (parent_table, type, part_interval, control, premake) VALUES
(p_parent_table, p_type, v_id_interval, p_control, p_premake);
EXECUTE 'SELECT @extschema@.create_id_partition('||quote_literal(p_parent_table)||','||quote_literal(p_control)||','
||v_id_interval||','||quote_literal(v_partition_id)||')' INTO v_last_partition_name;
-- Doing separate update because create function needs parent table in config table for apply_grants()
UPDATE @extschema@.part_config SET last_partition = v_last_partition_name WHERE parent_table = p_parent_table;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'ID partitions premade: '||p_premake);
END IF;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Creating partition function');
END IF;
IF p_type = 'time-static' OR p_type = 'time-dynamic' THEN
EXECUTE 'SELECT @extschema@.create_time_function('||quote_literal(p_parent_table)||')';
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Time function created');
END IF;
ELSIF p_type = 'id-static' OR p_type = 'id-dynamic' THEN
v_current_id := COALESCE(v_max, 0);
EXECUTE 'SELECT @extschema@.create_id_function('||quote_literal(p_parent_table)||','||v_current_id||')';
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'ID function created');
END IF;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Creating partition trigger');
END IF;
EXECUTE 'SELECT @extschema@.create_trigger('||quote_literal(p_parent_table)||')';
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
EXCEPTION
WHEN OTHERS THEN
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
IF v_job_id IS NULL THEN
v_job_id := add_job('PARTMAN CREATE PARENT: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Partition creation for table '||p_parent_table||' failed');
ELSIF v_step_id IS NULL THEN
v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
RAISE EXCEPTION '%', SQLERRM;
END
$$;
/*
* Create the next partition in sequence for a time-based partition set
*/
CREATE OR REPLACE FUNCTION create_next_time_partition (p_parent_table text) RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
v_control text;
v_datetime_string text;
v_last_partition text;
v_next_partition_timestamp timestamp;
v_next_year text;
v_part_interval interval;
v_quarter text;
v_tablename text;
v_type text;
v_year text;
BEGIN
SELECT type
, part_interval::interval
, control
, datetime_string
, last_partition
FROM @extschema@.part_config
WHERE parent_table = p_parent_table
AND (type = 'time-static' OR type = 'time-dynamic')
INTO v_type, v_part_interval, v_control, v_datetime_string, v_last_partition;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
END IF;
-- Double check that last created partition exists
IF v_last_partition IS NOT NULL THEN
SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = v_last_partition;
IF v_tablename IS NULL THEN
RAISE EXCEPTION 'ERROR: previous partition table missing. Unable to determine next proper partition in sequence.';
END IF;
ELSE
RAISE EXCEPTION 'ERROR: last known partition missing from config table for parent table %.', p_parent_table;
END IF;
-- pull out datetime portion of last partition's tablename to make the next one
IF v_part_interval != '3 months' THEN
v_next_partition_timestamp := to_timestamp(substring(v_last_partition from char_length(p_parent_table||'_p')+1), v_datetime_string) + v_part_interval;
ELSE
-- to_timestamp doesn't recognize 'Q' date string formater. Handle it
v_year := split_part(substring(v_last_partition from char_length(p_parent_table||'_p')+1), 'q', 1);
v_next_year := extract('year' from to_date(v_year, 'YYYY')+'1year'::interval);
v_quarter := split_part(substring(v_last_partition from char_length(p_parent_table||'_p')+1), 'q', 2);
CASE
WHEN v_quarter = '1' THEN
v_next_partition_timestamp := to_timestamp(v_year || '-04-01', 'YYYY-MM-DD');
WHEN v_quarter = '2' THEN
v_next_partition_timestamp := to_timestamp(v_year || '-07-01', 'YYYY-MM-DD');
WHEN v_quarter = '3' THEN
v_next_partition_timestamp := to_timestamp(v_year || '-10-01', 'YYYY-MM-DD');
WHEN v_quarter = '4' THEN
v_next_partition_timestamp := to_timestamp(v_next_year || '-01-01', 'YYYY-MM-DD');
END CASE;
END IF;
EXECUTE 'SELECT @extschema@.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||','||quote_literal(v_part_interval)||','
||quote_literal(v_datetime_string)||','||quote_literal(ARRAY[v_next_partition_timestamp])||')' INTO v_last_partition;
IF v_last_partition IS NOT NULL THEN
UPDATE @extschema@.part_config SET last_partition = v_last_partition WHERE parent_table = p_parent_table;
END IF;
END
$$;
/*
* Function to create a child table in a time-based partition set
*/
CREATE OR REPLACE FUNCTION create_time_partition (p_parent_table text, p_control text, p_interval interval, p_datetime_string text, p_partition_times timestamp[]) RETURNS text
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
v_job_id bigint;
v_jobmon_schema text;
v_old_search_path text;
v_partition_name text;
v_partition_timestamp_end timestamp;
v_partition_timestamp_start timestamp;
v_quarter text;
v_step_id bigint;
v_tablename text;
v_time timestamp;
v_year text;
BEGIN
SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
END IF;
FOREACH v_time IN ARRAY p_partition_times LOOP
v_partition_name := p_parent_table || '_p';
IF p_interval = '1 year' OR p_interval = '1 month' OR p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
v_partition_name := v_partition_name || to_char(v_time, 'YYYY');
IF p_interval = '1 month' OR p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
v_partition_name := v_partition_name || '_' || to_char(v_time, 'MM');
IF p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
v_partition_name := v_partition_name || '_' || to_char(v_time, 'DD');
IF p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
v_partition_name := v_partition_name || '_' || to_char(v_time, 'HH24');
IF p_interval <> '30 mins' AND p_interval <> '15 mins' THEN
v_partition_name := v_partition_name || '00';
ELSIF p_interval = '15 mins' THEN
IF date_part('minute', v_time) < 15 THEN
v_partition_name := v_partition_name || '00';
ELSIF date_part('minute', v_time) >= 15 AND date_part('minute', v_time) < 30 THEN
v_partition_name := v_partition_name || '15';
ELSIF date_part('minute', v_time) >= 30 AND date_part('minute', v_time) < 45 THEN
v_partition_name := v_partition_name || '30';
ELSE
v_partition_name := v_partition_name || '45';
END IF;
ELSIF p_interval = '30 mins' THEN
IF date_part('minute', v_time) < 30 THEN
v_partition_name := v_partition_name || '00';
ELSE
v_partition_name := v_partition_name || '30';
END IF;
END IF;
END IF; -- end hour IF
END IF; -- end day IF
END IF; -- end month IF
ELSIF p_interval = '1 week' THEN
v_partition_name := v_partition_name || to_char(v_time, 'IYYY') || 'w' || to_char(v_time, 'IW');
END IF; -- end year/week IF
-- pull out datetime portion of last partition's tablename
v_partition_timestamp_start := to_timestamp(substring(v_partition_name from char_length(p_parent_table||'_p')+1), p_datetime_string);
v_partition_timestamp_end := to_timestamp(substring(v_partition_name from char_length(p_parent_table||'_p')+1), p_datetime_string) + p_interval;
-- "Q" is ignored in to_timestamp, so handle special case
IF p_interval = '3 months' THEN
v_year := to_char(v_time, 'YYYY');
v_quarter := to_char(v_time, 'Q');
v_partition_name := v_partition_name || v_year || 'q' || v_quarter;
CASE
WHEN v_quarter = '1' THEN
v_partition_timestamp_start := to_timestamp(v_year || '-01-01', 'YYYY-MM-DD');
WHEN v_quarter = '2' THEN
v_partition_timestamp_start := to_timestamp(v_year || '-04-01', 'YYYY-MM-DD');
WHEN v_quarter = '3' THEN
v_partition_timestamp_start := to_timestamp(v_year || '-07-01', 'YYYY-MM-DD');
WHEN v_quarter = '4' THEN
v_partition_timestamp_start := to_timestamp(v_year || '-10-01', 'YYYY-MM-DD');
END CASE;
v_partition_timestamp_end := v_partition_timestamp_start + p_interval;
END IF;
SELECT schemaname ||'.'|| tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name;
IF v_tablename IS NOT NULL THEN
CONTINUE;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_partition_timestamp_start||' to '||(v_partition_timestamp_end-'1sec'::interval));
END IF;
IF position('.' in p_parent_table) > 0 THEN
v_tablename := substring(v_partition_name from position('.' in v_partition_name)+1);
END IF;
EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING INDEXES)';
EXECUTE 'ALTER TABLE '||v_partition_name||' ADD CONSTRAINT '||v_tablename||'_partition_check
CHECK ('||p_control||'>='||quote_literal(v_partition_timestamp_start)||' AND '||p_control||'<'||quote_literal(v_partition_timestamp_end)||')';
EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
END IF;
END LOOP;
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMAN APPLYING GRANTS: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Looping through all child tables applying privileges of the parent');
END IF;
PERFORM @extschema@.apply_grants(p_parent_table);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
END IF;
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
RETURN v_partition_name;
EXCEPTION
WHEN OTHERS THEN
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
IF v_job_id IS NULL THEN
v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Partition maintenance for table '||p_parent_table||' failed');
ELSIF v_step_id IS NULL THEN
v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
RAISE EXCEPTION '%', SQLERRM;
END
$$;
/*
* Function to create id partitions
*/
CREATE OR REPLACE FUNCTION create_id_partition (p_parent_table text, p_control text, p_interval bigint, p_partition_ids bigint[]) RETURNS text
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
v_job_id bigint;
v_jobmon_schema text;
v_old_search_path text;
v_partition_name text;
v_step_id bigint;
v_tablename text;
v_id bigint;
BEGIN
SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
END IF;
FOREACH v_id IN ARRAY p_partition_ids LOOP
v_partition_name := p_parent_table||'_p'||v_id;
SELECT schemaname ||'.'|| tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name;
IF v_tablename IS NOT NULL THEN
CONTINUE;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_id||' to '||(v_id + p_interval)-1);
END IF;
IF position('.' in p_parent_table) > 0 THEN
v_tablename := substring(v_partition_name from position('.' in v_partition_name)+1);
END IF;
EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING INDEXES)';
EXECUTE 'ALTER TABLE '||v_partition_name||' ADD CONSTRAINT '||v_tablename||'_partition_check
CHECK ('||p_control||'>='||quote_literal(v_id)||' AND '||p_control||'<'||quote_literal(v_id + p_interval)||')';
EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
END IF;
END LOOP;
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMAN APPLYING GRANTS: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Looping through all child tables applying privileges of the parent');
END IF;
PERFORM @extschema@.apply_grants(p_parent_table);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
END IF;
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
RETURN v_partition_name;
EXCEPTION
WHEN OTHERS THEN
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
IF v_job_id IS NULL THEN
v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Partition maintenance for table '||p_parent_table||' failed');
ELSIF v_step_id IS NULL THEN
v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
RAISE EXCEPTION '%', SQLERRM;
END
$$;
|