/usr/share/postgresql/9.6/extension/mimeo--0.4.1--0.4.2.sql is in postgresql-9.6-mimeo 1.4.4-1.
This file is owned by root:root, with mode 0o644.
The actual contents of the file can be viewed below.
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 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 | -- Fix exceptions in remaining functions to handle an exception being thrown before first logged step. inserter/updater were fixed in 0.4.1
/*
* Snap refresh to repull all table data
*/
CREATE OR REPLACE FUNCTION refresh_snap(p_destination text, p_debug boolean) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
v_adv_lock boolean;
v_cols_n_types text;
v_cols text;
v_create_sql text;
v_dblink_schema text;
v_dblink text;
v_dest_table text;
v_exists int;
v_insert_sql text;
v_job_id int;
v_jobmon_schema text;
v_job_name text;
v_lcols_array text[];
v_local_sql text;
v_l text;
v_match boolean := 'f';
v_old_search_path text;
v_parts record;
v_post_script text[];
v_rcols_array text[];
v_refresh_snap text;
v_remote_sql text;
v_rowcount bigint;
v_r text;
v_snap text;
v_source_table text;
v_step_id int;
v_table_exists int;
v_view_definition text;
BEGIN
IF p_debug IS DISTINCT FROM true THEN
PERFORM set_config( 'client_min_messages', 'notice', true );
END IF;
v_job_name := 'Refresh Snap: '||p_destination;
SELECT nspname INTO v_dblink_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'dblink' AND e.extnamespace = n.oid;
SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
-- Set custom search path to allow easier calls to other functions, especially job logging
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||','||v_dblink_schema||''',''false'')';
v_job_id := add_job(v_job_name);
PERFORM gdb(p_debug,'Job ID: '||v_job_id::text);
-- Take advisory lock to prevent multiple calls to function overlapping and causing possible deadlock
v_adv_lock := pg_try_advisory_lock(hashtext('refresh_snap'), hashtext(v_job_name));
IF v_adv_lock = 'false' THEN
v_step_id := add_step(v_job_id,'Obtaining advisory lock for job: '||v_job_name);
PERFORM gdb(p_debug,'Obtaining advisory lock FAILED for job: '||v_job_name);
PERFORM update_step(v_step_id, 'OK','Found concurrent job. Exiting gracefully');
PERFORM close_job(v_job_id);
RETURN;
END IF;
v_step_id := add_step(v_job_id,'Grabbing Mapping, Building SQL');
SELECT source_table, dest_table, dblink, post_script INTO v_source_table, v_dest_table, v_dblink, v_post_script FROM refresh_config_snap
WHERE dest_table = p_destination;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: This table is not set up for snapshot replication: %',v_job_name;
END IF;
-- checking for current view
SELECT definition INTO v_view_definition FROM pg_views where
((schemaname || '.') || viewname)=v_dest_table;
v_exists := strpos(v_view_definition, 'snap1');
IF v_exists > 0 THEN
v_snap := '_snap2';
ELSE
v_snap := '_snap1';
END IF;
v_refresh_snap := v_dest_table||v_snap;
PERFORM gdb(p_debug,'v_refresh_snap: '||v_refresh_snap::text);
-- init sql statements
v_remote_sql := 'SELECT array_to_string(array_agg(attname),'','') as cols, array_to_string(array_agg(attname||'' ''||atttypid::regtype::text),'','') as cols_n_types FROM pg_attribute WHERE attnum > 0 AND attisdropped is false AND attrelid = ' || quote_literal(v_source_table) || '::regclass';
v_remote_sql := 'SELECT cols, cols_n_types FROM dblink(auth(' || v_dblink || '), ' || quote_literal(v_remote_sql) || ') t (cols text, cols_n_types text)';
perform gdb(p_debug,'v_remote_sql: '||v_remote_sql);
EXECUTE v_remote_sql INTO v_cols, v_cols_n_types;
perform gdb(p_debug,'v_cols: '||v_cols);
perform gdb(p_debug,'v_cols_n_types: '||v_cols_n_types);
v_remote_sql := 'SELECT '||v_cols||' FROM '||v_source_table;
v_insert_sql := 'INSERT INTO ' || v_refresh_snap || ' SELECT '||v_cols||' FROM dblink(auth('||v_dblink||'),'||quote_literal(v_remote_sql)||') t ('||v_cols_n_types||')';
PERFORM update_step(v_step_id, 'OK','Done');
v_step_id := add_step(v_job_id,'Truncate non-active snap table');
-- Create snap table if it doesn't exist
SELECT string_to_array(v_refresh_snap, '.') AS oparts INTO v_parts;
SELECT INTO v_table_exists count(1) FROM pg_tables
WHERE schemaname = v_parts.oparts[1] AND
tablename = v_parts.oparts[2];
IF v_table_exists = 0 THEN
PERFORM gdb(p_debug,'Snap table does not exist. Creating... ');
v_create_sql := 'CREATE TABLE ' || v_refresh_snap || ' (' || v_cols_n_types || ')';
perform gdb(p_debug,'v_create_sql: '||v_create_sql::text);
EXECUTE v_create_sql;
ELSE
/* Check local column definitions against remote and recreate table if different. Allows automatic recreation of
snap tables if columns change (add, drop type change) */
v_local_sql := 'SELECT array_agg(attname||'' ''||atttypid::regtype::text) as cols_n_types FROM pg_attribute WHERE attnum > 0 AND attisdropped is false AND attrelid = ' || quote_literal(v_refresh_snap) || '::regclass';
PERFORM gdb(p_debug,'v_local_sql: '||v_local_sql::text);
EXECUTE v_local_sql INTO v_lcols_array;
SELECT string_to_array(v_cols_n_types, ',') AS cols INTO v_rcols_array;
-- Check to see if there's a change in the column structure on the remote
FOREACH v_r IN ARRAY v_rcols_array LOOP
v_match := 'f';
FOREACH v_l IN ARRAY v_lcols_array LOOP
IF v_r = v_l THEN
v_match := 't';
EXIT;
END IF;
END LOOP;
END LOOP;
IF v_match = 'f' THEN
EXECUTE 'DROP TABLE ' || v_refresh_snap;
EXECUTE 'DROP VIEW ' || v_dest_table;
v_create_sql := 'CREATE TABLE ' || v_refresh_snap || ' (' || v_cols_n_types || ')';
PERFORM gdb(p_debug,'v_create_sql: '||v_create_sql::text);
EXECUTE v_create_sql;
v_step_id := add_step(v_job_id,'Source table structure changed.');
PERFORM update_step(v_step_id, 'OK','Tables and view dropped and recreated. Please double-check snap table attributes (permissions, indexes, etc');
PERFORM gdb(p_debug,'Source table structure changed. Tables and view dropped and recreated. Please double-check snap table attributes (permissions, indexes, etc)');
END IF;
-- truncate non-active snap table
EXECUTE 'TRUNCATE TABLE ' || v_refresh_snap;
PERFORM update_step(v_step_id, 'OK','Done');
END IF;
-- populating snap table
v_step_id := add_step(v_job_id,'Inserting records into local table');
PERFORM gdb(p_debug,'Inserting rows... '||v_insert_sql);
EXECUTE v_insert_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM update_step(v_step_id, 'OK','Inserted '||v_rowcount||' records');
IF v_rowcount IS NOT NULL THEN
EXECUTE 'ANALYZE ' ||v_refresh_snap;
SET statement_timeout='30 min';
-- swap view
v_step_id := add_step(v_job_id,'Swap view to '||v_refresh_snap);
PERFORM gdb(p_debug,'Swapping view to '||v_refresh_snap);
EXECUTE 'CREATE OR REPLACE VIEW '||v_dest_table||' AS SELECT * FROM '||v_refresh_snap;
PERFORM update_step(v_step_id, 'OK','View Swapped');
v_step_id := add_step(v_job_id,'Updating last value');
UPDATE refresh_config_snap set last_value = now() WHERE dest_table = p_destination;
PERFORM update_step(v_step_id, 'OK','Done');
-- Runs special sql to fix indexes, permissions, etc on recreated objects
IF v_match = 'f' AND v_post_script IS NOT NULL THEN
v_step_id := add_step(v_job_id,'Applying post_script sql commands due to schema change');
PERFORM @extschema@.post_script(v_dest_table);
PERFORM update_step(v_step_id, 'OK','Done');
END IF;
PERFORM close_job(v_job_id);
ELSE
RAISE EXCEPTION 'No rows found in source table';
END IF;
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
PERFORM pg_advisory_unlock(hashtext('refresh_snap'), hashtext(v_job_name));
EXCEPTION
-- See if there's exception to handle for the timeout
WHEN OTHERS THEN
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||','||v_dblink_schema||''',''false'')';
IF v_step_id IS NULL THEN
v_step_id := jobmon.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);
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
PERFORM pg_advisory_unlock(hashtext('refresh_snap'), hashtext(v_job_name));
RAISE EXCEPTION '%', SQLERRM;
END
$$;
/*
* Refresh based on DML (Insert, Update, Delete)
*/
CREATE OR REPLACE FUNCTION refresh_dml(p_destination text, p_debug boolean, int default 100000) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
v_adv_lock boolean;
v_cols_n_types text;
v_cols text;
v_control text;
v_create_f_sql text;
v_dblink_schema text;
v_dblink text;
v_delete_sql text;
v_dest_table text;
v_exec_status text;
v_field text;
v_filter text[];
v_insert_sql text;
v_job_id int;
v_jobmon_schema text;
v_job_name text;
v_last_value_sql text;
v_old_search_path text;
v_pk_counter int := 2;
v_pk_field_csv text;
v_pk_field text[];
v_pk_type text[];
v_pk_where text;
v_remote_f_sql text;
v_remote_q_sql text;
v_rowcount bigint;
v_source_table text;
v_step_id int;
v_tmp_table text;
v_trigger_delete text;
v_trigger_update text;
v_with_update text;
BEGIN
IF p_debug IS DISTINCT FROM true THEN
PERFORM set_config( 'client_min_messages', 'warning', true );
END IF;
v_job_name := 'Refresh DML: '||p_destination;
SELECT nspname INTO v_dblink_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'dblink' AND e.extnamespace = n.oid;
SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
-- Set custom search path to allow easier calls to other functions, especially job logging
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||','||v_dblink_schema||''',''false'')';
SELECT source_table, dest_table, 'tmp_'||replace(dest_table,'.','_'), dblink, control, pk_field, pk_type, filter FROM refresh_config_dml
WHERE dest_table = p_destination INTO v_source_table, v_dest_table, v_tmp_table, v_dblink, v_control, v_pk_field, v_pk_type, v_filter;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: no mapping found for %',v_job_name;
END IF;
v_job_id := add_job(quote_literal(v_job_name));
PERFORM gdb(p_debug,'Job ID: '||v_job_id::text);
-- Take advisory lock to prevent multiple calls to function overlapping
v_adv_lock := pg_try_advisory_lock(hashtext('refresh_dml'), hashtext(v_job_name));
IF v_adv_lock = 'false' THEN
v_step_id := add_step(v_job_id,'Obtaining advisory lock for job: '||v_job_name);
PERFORM gdb(p_debug,'Obtaining advisory lock FAILED for job: '||v_job_name);
PERFORM update_step(v_step_id, 'OK','Found concurrent job. Exiting gracefully');
PERFORM close_job(v_job_id);
RETURN;
END IF;
v_step_id := add_step(v_job_id,'Grabbing Boundries, Building SQL');
IF v_pk_field IS NULL OR v_pk_type IS NULL THEN
RAISE EXCEPTION 'ERROR: primary key fields in refresh_config_dml must be defined';
END IF;
-- determine column list, column type list
IF v_filter IS NULL THEN
SELECT array_to_string(array_agg(attname),','), array_to_string(array_agg(attname||' '||atttypid::regtype::text),',') FROM
pg_attribute WHERE attnum > 0 AND attisdropped is false AND attrelid = p_destination::regclass INTO v_cols, v_cols_n_types;
ELSE
-- ensure all primary key columns are included in any column filters
FOREACH v_field IN ARRAY v_pk_field LOOP
IF v_field = ANY(v_filter) THEN
CONTINUE;
ELSE
RAISE EXCEPTION 'ERROR: filter list did not contain all columns that compose primary key for %',v_job_name;
END IF;
END LOOP;
SELECT array_to_string(array_agg(attname),','), array_to_string(array_agg(attname||' '||atttypid::regtype::text),',') FROM
(SELECT unnest(filter) FROM refresh_config_dml WHERE dest_table = p_destination) x
JOIN pg_attribute ON (unnest=attname::text AND attrelid=p_destination::regclass) INTO v_cols, v_cols_n_types;
END IF;
-- init sql statements
v_pk_field_csv := array_to_string(v_pk_field,',');
v_with_update := 'WITH a AS (SELECT '||v_pk_field_csv||' FROM '|| v_control ||' ORDER BY 1 LIMIT '|| $3 ||') UPDATE '||v_control||' b SET processed = true FROM a WHERE a.'||v_pk_field[1]||' = b.'||v_pk_field[1];
IF array_length(v_pk_field, 1) > 1 THEN
v_pk_where := '';
WHILE v_pk_counter <= array_length(v_pk_field,1) LOOP
v_pk_where := v_pk_where || ' AND a.'||v_pk_field[v_pk_counter]||' = b.'||v_pk_field[v_pk_counter];
v_pk_counter := v_pk_counter + 1;
END LOOP;
END IF;
IF v_pk_where IS NOT NULL THEN
v_with_update := v_with_update || v_pk_where;
END IF;
PERFORM gdb(p_debug, v_with_update);
v_trigger_update := 'SELECT dblink_exec(auth('||v_dblink||'),'|| quote_literal(v_with_update)||')';
v_remote_q_sql := 'SELECT DISTINCT '||v_pk_field_csv||' FROM '||v_control||' WHERE processed = true';
v_remote_f_sql := 'SELECT '||v_cols||' FROM '||v_source_table||' JOIN ('||v_remote_q_sql||') x USING ('||v_pk_field_csv||')';
v_create_f_sql := 'CREATE TEMP TABLE '||v_tmp_table||'_full AS SELECT '||v_cols||'
FROM dblink(auth('||v_dblink||'),'||quote_literal(v_remote_f_sql)||') t ('||v_cols_n_types||')';
v_delete_sql := 'DELETE FROM '||v_dest_table||' a USING '||v_tmp_table||'_full b WHERE a.'||v_pk_field[1]||'= b.'||v_pk_field[1];
IF array_length(v_pk_field, 1) > 1 THEN
v_delete_sql := v_delete_sql || v_pk_where;
END IF;
v_insert_sql := 'INSERT INTO '||v_dest_table||'('||v_cols||') SELECT '||v_cols||' FROM '||v_tmp_table||'_full';
v_trigger_delete := 'SELECT dblink_exec(auth('||v_dblink||'),'||quote_literal('DELETE FROM '||v_control||' WHERE processed = true')||')';
PERFORM update_step(v_step_id, 'OK','Remote table is '||v_source_table);
-- update remote entries
v_step_id := add_step(v_job_id,'Updating remote trigger table');
PERFORM gdb(p_debug,v_trigger_update);
EXECUTE v_trigger_update INTO v_exec_status;
PERFORM update_step(v_step_id, 'OK','Result was '||v_exec_status);
-- create temp table for insertion
v_step_id := add_step(v_job_id,'Create temp table from remote full table');
PERFORM gdb(p_debug,v_create_f_sql);
EXECUTE v_create_f_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Temp table row count '||v_rowcount::text);
IF v_rowcount < 1 THEN
PERFORM update_step(v_step_id, 'OK','No new rows found');
EXECUTE 'DROP TABLE IF EXISTS '||v_tmp_table||'_full';
PERFORM close_job(v_job_id);
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
PERFORM pg_advisory_unlock(hashtext('refresh_dml'), hashtext(v_job_name));
RETURN;
END IF;
PERFORM update_step(v_step_id, 'OK','Table contains '||v_rowcount||' records');
-- remove records from local table
v_step_id := add_step(v_job_id,'Deleting records from local table');
PERFORM gdb(p_debug,v_delete_sql);
EXECUTE v_delete_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Rows removed from local table before applying changes: '||v_rowcount::text);
PERFORM update_step(v_step_id, 'OK','Removed '||v_rowcount||' records');
-- insert records to local table
v_step_id := add_step(v_job_id,'Inserting new records into local table');
PERFORM gdb(p_debug,v_insert_sql);
EXECUTE v_insert_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Rows inserted: '||v_rowcount::text);
PERFORM update_step(v_step_id, 'OK','Inserted '||v_rowcount||' records');
-- clean out rows from txn table
v_step_id := add_step(v_job_id,'Cleaning out rows from txn table');
PERFORM gdb(p_debug,v_trigger_delete);
EXECUTE v_trigger_delete INTO v_exec_status;
PERFORM update_step(v_step_id, 'OK','Result was '||v_exec_status);
-- update activity status
v_step_id := add_step(v_job_id,'Updating last_value in config table');
v_last_value_sql := 'UPDATE refresh_config_dml SET last_value = '|| quote_literal(current_timestamp::timestamp) ||' WHERE dest_table = ' ||quote_literal(p_destination);
PERFORM gdb(p_debug,v_last_value_sql);
EXECUTE v_last_value_sql;
PERFORM update_step(v_step_id, 'OK','Last Value was '||current_timestamp);
PERFORM close_job(v_job_id);
EXECUTE 'DROP TABLE IF EXISTS '||v_tmp_table||'_full';
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
PERFORM pg_advisory_unlock(hashtext('refresh_dml'), hashtext(v_job_name));
EXCEPTION
WHEN others THEN
-- Exception block resets path, so have to reset it again
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||','||v_dblink_schema||''',''false'')';
IF v_step_id IS NULL THEN
v_step_id := jobmon.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);
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
PERFORM pg_advisory_unlock(hashtext('refresh_dml'), hashtext(v_job_name));
RAISE EXCEPTION '%', SQLERRM;
END
$$;
/*
* Refresh based on DML (Insert, Update, Delete), but logs all deletes on the destination table
* Destination table requires extra column: source_deleted timestamptz
*/
CREATE OR REPLACE FUNCTION refresh_logdel(p_destination text, p_debug boolean, int default 100000) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
v_adv_lock boolean;
v_boundry timestamptz;
v_cols_n_types text;
v_cols text;
v_control text;
v_create_d_sql text;
v_create_f_sql text;
v_dblink_schema text;
v_dblink text;
v_delete_d_sql text;
v_delete_f_sql text;
v_dest_table text;
v_exec_status text;
v_field text;
v_filter text[];
v_insert_deleted_sql text;
v_insert_sql text;
v_job_id int;
v_jobmon_schema text;
v_job_name text;
v_last_value_sql text;
v_old_search_path text;
v_pk_counter int := 2;
v_pk_field_csv text;
v_pk_field text[];
v_pk_type text[];
v_pk_where text;
v_remote_d_sql text;
v_remote_f_sql text;
v_remote_q_sql text;
v_rowcount bigint;
v_source_table text;
v_step_id int;
v_tmp_table text;
v_trigger_delete text;
v_trigger_update text;
v_with_update text;
BEGIN
IF p_debug IS DISTINCT FROM true THEN
PERFORM set_config( 'client_min_messages', 'warning', true );
END IF;
v_job_name := 'Refresh Log Del: '||p_destination;
SELECT nspname INTO v_dblink_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'dblink' AND e.extnamespace = n.oid;
SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
-- Set custom search path to allow easier calls to other functions, especially job logging
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||','||v_dblink_schema||''',''false'')';
SELECT source_table, dest_table, 'tmp_'||replace(dest_table,'.','_'), dblink, control, pk_field, pk_type, filter FROM refresh_config_logdel
WHERE dest_table = p_destination INTO v_source_table, v_dest_table, v_tmp_table, v_dblink, v_control, v_pk_field, v_pk_type, v_filter;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: no mapping found for %',v_job_name;
END IF;
v_job_id := add_job(quote_literal(v_job_name));
PERFORM gdb(p_debug,'Job ID: '||v_job_id::text);
-- Take advisory lock to prevent multiple calls to function overlapping
v_adv_lock := pg_try_advisory_lock(hashtext('refresh_logdel'), hashtext(v_job_name));
IF v_adv_lock = 'false' THEN
v_step_id := add_step(v_job_id,'Obtaining advisory lock for job: '||v_job_name);
PERFORM gdb(p_debug,'Obtaining advisory lock FAILED for job: '||v_job_name);
PERFORM update_step(v_step_id, 'OK','Found concurrent job. Exiting gracefully');
PERFORM close_job(v_job_id);
RETURN;
END IF;
v_step_id := add_step(v_job_id,'Grabbing Boundries, Building SQL');
IF v_pk_field IS NULL OR v_pk_type IS NULL THEN
RAISE EXCEPTION 'ERROR: primary key fields in refresh_config_logdel must be defined';
END IF;
-- determine column list, column type list
IF v_filter IS NULL THEN
SELECT array_to_string(array_agg(attname),','), array_to_string(array_agg(attname||' '||atttypid::regtype::text),',') FROM
pg_attribute WHERE attnum > 0 AND attisdropped is false AND attrelid = p_destination::regclass AND attname != 'source_deleted' INTO v_cols, v_cols_n_types;
ELSE
-- ensure all primary key columns are included in any column filters
FOREACH v_field IN ARRAY v_pk_field LOOP
IF v_field = ANY(v_filter) THEN
CONTINUE;
ELSE
RAISE EXCEPTION 'ERROR: filter list did not contain all columns that compose primary key for %',v_job_name;
END IF;
END LOOP;
SELECT array_to_string(array_agg(attname),','), array_to_string(array_agg(attname||' '||atttypid::regtype::text),',') FROM
(SELECT unnest(filter) FROM refresh_config_logdel WHERE dest_table = p_destination) x
JOIN pg_attribute ON (unnest=attname::text AND attrelid=p_destination::regclass) WHERE attname != 'source_deleted' INTO v_cols, v_cols_n_types;
END IF;
-- init sql statements
v_pk_field_csv := array_to_string(v_pk_field,',');
v_with_update := 'WITH a AS (SELECT '||v_pk_field_csv||' FROM '|| v_control ||' ORDER BY 1 LIMIT '|| $3 ||') UPDATE '||v_control||' b SET processed = true FROM a WHERE a.'||v_pk_field[1]||' = b.'||v_pk_field[1];
IF array_length(v_pk_field, 1) > 1 THEN
v_pk_where := '';
WHILE v_pk_counter <= array_length(v_pk_field,1) LOOP
v_pk_where := v_pk_where || ' AND a.'||v_pk_field[v_pk_counter]||' = b.'||v_pk_field[v_pk_counter];
v_pk_counter := v_pk_counter + 1;
END LOOP;
END IF;
IF v_pk_where IS NOT NULL THEN
v_with_update := v_with_update || v_pk_where;
END IF;
PERFORM gdb(p_debug, v_with_update);
v_trigger_update := 'SELECT dblink_exec(auth('||v_dblink||'),'|| quote_literal(v_with_update)||')';
v_remote_q_sql := 'SELECT DISTINCT '||v_pk_field_csv||' FROM '||v_control||' WHERE processed = true and source_deleted IS NULL';
v_remote_f_sql := 'SELECT '||v_cols||' FROM '||v_source_table||' JOIN ('||v_remote_q_sql||') x USING ('||v_pk_field_csv||')';
v_create_f_sql := 'CREATE TEMP TABLE '||v_tmp_table||'_full AS SELECT '||v_cols||'
FROM dblink(auth('||v_dblink||'),'||quote_literal(v_remote_f_sql)||') t ('||v_cols_n_types||')';
v_remote_d_sql = 'SELECT '||v_cols||', source_deleted FROM '||v_control||' WHERE processed = true and source_deleted IS NOT NULL';
v_create_d_sql = 'CREATE TEMP TABLE '||v_tmp_table||'_deleted AS SELECT '||v_cols||', source_deleted
FROM dblink(auth('||v_dblink||'),'||quote_literal(v_remote_d_sql)||') t ('||v_cols_n_types||', source_deleted timestamptz)';
v_delete_f_sql := 'DELETE FROM '||v_dest_table||' a USING '||v_tmp_table||'_full b WHERE a.'||v_pk_field[1]||'= b.'||v_pk_field[1];
IF array_length(v_pk_field, 1) > 1 THEN
v_delete_f_sql := v_delete_f_sql || v_pk_where;
END IF;
-- remove rows that were deleted on source to ensure most recently deleted data is logged
v_delete_d_sql := 'DELETE FROM '||v_dest_table||' a USING '||v_tmp_table||'_deleted b WHERE a.'||v_pk_field[1]||'= b.'||v_pk_field[1];
IF array_length(v_pk_field, 1) > 1 THEN
v_delete_d_sql := v_delete_d_sql || v_pk_where;
END IF;
v_insert_sql := 'INSERT INTO '||v_dest_table||'('||v_cols||') SELECT '||v_cols||' FROM '||v_tmp_table||'_full';
v_insert_deleted_sql := 'INSERT INTO '||v_dest_table||'('||v_cols||', source_deleted) SELECT '||v_cols||', source_deleted FROM '||v_tmp_table||'_deleted';
v_trigger_delete := 'SELECT dblink_exec(auth('||v_dblink||'),'||quote_literal('DELETE FROM '||v_control||' WHERE processed = true')||')';
PERFORM update_step(v_step_id, 'OK','Remote table is '||v_source_table);
-- update remote entries
v_step_id := add_step(v_job_id,'Updating remote trigger table');
PERFORM gdb(p_debug,v_trigger_update);
EXECUTE v_trigger_update INTO v_exec_status;
PERFORM update_step(v_step_id, 'OK','Result was '||v_exec_status);
-- create temp table for insertion (inserts/updates)
v_step_id := add_step(v_job_id,'Create temp table from remote full table');
PERFORM gdb(p_debug,v_create_f_sql);
EXECUTE v_create_f_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Insert/Update Temp table row count '||v_rowcount::text);
IF v_rowcount < 1 THEN
PERFORM update_step(v_step_id, 'OK','No new rows found');
EXECUTE 'DROP TABLE IF EXISTS '||v_tmp_table||'_full';
EXECUTE 'DROP TABLE IF EXISTS '||v_tmp_table||'_deleted';
PERFORM close_job(v_job_id);
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
PERFORM pg_advisory_unlock(hashtext('refresh_logdel'), hashtext(v_job_name));
RETURN;
END IF;
PERFORM update_step(v_step_id, 'OK','Table contains '||v_rowcount||' records');
-- create temp table for insertion (deleted rows)
v_step_id := add_step(v_job_id,'Create temp table from remote delete table');
PERFORM gdb(p_debug,v_create_d_sql);
EXECUTE v_create_d_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Delete Temp table row count '||v_rowcount::text);
PERFORM update_step(v_step_id, 'OK','Table contains '||v_rowcount||' records');
-- remove records from local table (inserts/updates)
v_step_id := add_step(v_job_id,'Deleting insert/update records from local table');
PERFORM gdb(p_debug,v_delete_f_sql);
EXECUTE v_delete_f_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Insert/Update rows removed from local table before applying changes: '||v_rowcount::text);
PERFORM update_step(v_step_id, 'OK','Removed '||v_rowcount||' records');
-- remove records from local table (deleted rows)
v_step_id := add_step(v_job_id,'Deleting removed records from local table');
PERFORM gdb(p_debug,v_delete_d_sql);
EXECUTE v_delete_d_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Deleted Rows removed from local table before applying changes: '||v_rowcount::text);
PERFORM update_step(v_step_id, 'OK','Removed '||v_rowcount||' records');
-- insert records to local table (inserts/updates)
v_step_id := add_step(v_job_id,'Inserting new/updated records into local table');
PERFORM gdb(p_debug,v_insert_sql);
EXECUTE v_insert_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Rows inserted: '||v_rowcount::text);
PERFORM update_step(v_step_id, 'OK','Inserted '||v_rowcount||' records');
-- insert records to local table (deleted rows to be kepts)
v_step_id := add_step(v_job_id,'Inserting deleted records into local table');
PERFORM gdb(p_debug,v_insert_deleted_sql);
EXECUTE v_insert_deleted_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
PERFORM gdb(p_debug,'Rows inserted: '||v_rowcount::text);
PERFORM update_step(v_step_id, 'OK','Inserted '||v_rowcount||' records');
-- clean out rows from txn table
v_step_id := add_step(v_job_id,'Cleaning out rows from txn table');
PERFORM gdb(p_debug,v_trigger_delete);
EXECUTE v_trigger_delete INTO v_exec_status;
PERFORM update_step(v_step_id, 'OK','Result was '||v_exec_status);
-- update activity status
v_step_id := add_step(v_job_id,'Updating last_value in config table');
v_last_value_sql := 'UPDATE refresh_config_logdel SET last_value = '|| quote_literal(current_timestamp::timestamp) ||' WHERE dest_table = ' ||quote_literal(p_destination);
PERFORM gdb(p_debug,v_last_value_sql);
EXECUTE v_last_value_sql;
PERFORM update_step(v_step_id, 'OK','Last Value was '||current_timestamp);
PERFORM close_job(v_job_id);
EXECUTE 'DROP TABLE IF EXISTS '||v_tmp_table||'_full';
EXECUTE 'DROP TABLE IF EXISTS '||v_tmp_table||'_deleted';
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
PERFORM pg_advisory_unlock(hashtext('refresh_logdel'), hashtext(v_job_name));
EXCEPTION
WHEN others THEN
-- Exception block resets path, so have to reset it again
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||','||v_dblink_schema||''',''false'')';
IF v_step_id IS NULL THEN
v_step_id := jobmon.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);
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
PERFORM pg_advisory_unlock(hashtext('refresh_logdel'), hashtext(v_job_name));
RAISE EXCEPTION '%', SQLERRM;
END
$$;
|