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
|
/*
* Refresh insert/update only table based on id control field
*/
CREATE FUNCTION refresh_updater_serial(p_destination text, p_limit integer DEFAULT NULL, p_repull boolean DEFAULT false, p_repull_start bigint DEFAULT NULL, p_repull_end bigint DEFAULT NULL, p_jobmon boolean DEFAULT NULL, p_lock_wait int DEFAULT NULL, p_debug boolean DEFAULT false) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
v_adv_lock boolean;
v_batch_limit_reached int := 0;
v_boundary_sql text;
v_boundary int;
v_cols_n_types text;
v_cols text;
v_condition text;
v_control text;
v_create_sql text;
v_cursor_name text;
v_dblink int;
v_dblink_name text;
v_dblink_schema text;
v_delete_sql text;
v_dest_schema_name text;
v_dest_table text;
v_dest_table_name text;
v_fetch_sql text;
v_field text;
v_filter text[];
v_full_refresh boolean := false;
v_insert_sql text;
v_job_id int;
v_jobmon boolean;
v_jobmon_schema text;
v_job_name text;
v_last_fetched bigint;
v_last_value bigint;
v_limit int;
v_link_exists boolean;
v_old_search_path text;
v_pk_counter int := 1;
v_pk_name text[];
v_remote_boundry_sql text;
v_remote_boundry timestamptz;
v_remote_sql text;
v_rowcount bigint := 0;
v_source_table text;
v_sql text;
v_src_schema_name text;
v_src_table_name text;
v_step_id int;
v_total bigint := 0;
BEGIN
-- Take advisory lock to prevent multiple calls to function overlapping
v_adv_lock := @extschema@.concurrent_lock_check(p_destination, p_lock_wait);
IF v_adv_lock = 'false' THEN
-- This code is known duplication of code below.
-- This is done in order to keep advisory lock as early in the code as possible to avoid race conditions and still log if issues are encountered.
v_job_name := 'Refresh Updater: '||p_destination;
SELECT jobmon INTO v_jobmon FROM @extschema@.refresh_config_updater WHERE dest_table = p_destination;
SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
v_jobmon := COALESCE(p_jobmon, v_jobmon);
IF v_jobmon IS TRUE AND v_jobmon_schema IS NULL THEN
RAISE EXCEPTION 'jobmon config set to TRUE, but unable to determine if pg_jobmon extension is installed';
END IF;
IF v_jobmon THEN
EXECUTE format('SELECT %I.add_job(%L)', v_jobmon_schema, v_job_name) INTO v_job_id;
EXECUTE format('SELECT %I.add_step(%L, %L)', v_jobmon_schema, v_job_id, 'Obtaining advisory lock for job: '||v_job_name) INTO v_step_id;
EXECUTE format('SELECT %I.update_step(%L, %L, %L)', v_jobmon_schema, v_step_id, 'WARNING', 'Found concurrent job. Exiting gracefully');
EXECUTE format('SELECT %I.fail_job(%L, %L)', v_jobmon_schema, v_job_id, 2);
END IF;
PERFORM @extschema@.gdb(p_debug,'Obtaining advisory lock FAILED for job: '||v_job_name);
RAISE DEBUG 'Found concurrent job. Exiting gracefully';
RETURN;
END IF;
IF p_debug IS DISTINCT FROM true THEN
PERFORM set_config( 'client_min_messages', 'warning', true );
END IF;
v_job_name := 'Refresh Updater: '||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;
IF p_jobmon IS TRUE AND v_jobmon_schema IS NULL THEN
RAISE EXCEPTION 'p_jobmon parameter set to TRUE, but unable to determine if pg_jobmon extension is installed';
END IF;
v_dblink_name := @extschema@.check_name_length('mimeo_updater_refresh_'||p_destination);
-- 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@,'||COALESCE(v_jobmon_schema||',', '')||v_dblink_schema||',public'',''false'')';
SELECT source_table
, dest_table
, dblink
, control
, last_value
, boundary
, pk_name
, filter
, condition
, batch_limit
, jobmon
INTO v_source_table
, v_dest_table
, v_dblink
, v_control
, v_last_value
, v_boundary
, v_pk_name
, v_filter
, v_condition
, v_limit
, v_jobmon
FROM refresh_config_updater_serial
WHERE dest_table = p_destination;
IF NOT FOUND THEN
RAISE EXCEPTION 'Destination table given in argument (%) is not managed by mimeo.', p_destination;
END IF;
-- Allow override with parameter
v_jobmon := COALESCE(p_jobmon, v_jobmon);
SELECT schemaname, tablename
INTO v_dest_schema_name, v_dest_table_name
FROM pg_catalog.pg_tables
WHERE schemaname||'.'||tablename = v_dest_table;
IF v_dest_table_name IS NULL THEN
RAISE EXCEPTION 'Destination table is missing (%)', v_dest_table;
END IF;
IF v_jobmon THEN
v_job_id := add_job(v_job_name);
PERFORM gdb(p_debug,'Job ID: '||v_job_id::text);
END IF;
IF v_jobmon THEN
v_step_id := add_step(v_job_id,'Building SQL');
END IF;
-- ensure all primary key columns are included in any column filters
IF v_filter IS NOT NULL THEN
FOREACH v_field IN ARRAY v_pk_name LOOP
IF v_field = ANY(v_filter) THEN
CONTINUE;
ELSE
RAISE EXCEPTION 'Filter list did not contain all columns that compose primary/unique key for %',v_job_name;
END IF;
END LOOP;
END IF;
PERFORM dblink_connect(v_dblink_name, auth(v_dblink));
SELECT array_to_string(p_cols, ',')
, array_to_string(p_cols_n_types, ',')
, p_source_schema_name
, p_source_table_name
INTO v_cols
, v_cols_n_types
, v_src_schema_name
, v_src_table_name
FROM manage_dest_table(v_dest_table, NULL, v_dblink_name, p_debug);
IF v_src_table_name IS NULL THEN
RAISE EXCEPTION 'Source table missing (%)', v_source_table;
END IF;
IF p_limit IS NOT NULL THEN
v_limit := p_limit;
END IF;
-- Unlike incremental time, there's nothing like CURRENT_TIMESTAMP to base the boundary on. So use the current source max to determine it.
-- For some reason this doesn't like using an int with %L (v_boundary) when making up the format command using dblink
v_sql := format('SELECT boundary FROM dblink(%L, ''SELECT max(%I) - %s AS boundary FROM %I.%I'') AS (boundary bigint)'
, v_dblink_name
, v_control
, v_boundary
, v_src_schema_name
, v_src_table_name);
PERFORM gdb(p_debug, v_sql);
EXECUTE v_sql INTO v_boundary;
-- Repull old data instead of normal new data pull
IF p_repull THEN
-- Repull ALL data if no start and end values set
IF p_repull_start IS NULL AND p_repull_end IS NULL THEN
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK','Request to repull ALL data from source. This could take a while...');
END IF;
EXECUTE format('TRUNCATE %I.%I', v_dest_schema_name, v_dest_table_name);
-- Use upper boundary remote max to avoid edge case of multiple upper boundary values inserting during refresh
v_remote_sql := format('SELECT %s FROM %I.%I', v_cols, v_src_schema_name, v_src_table_name);
IF v_condition IS NOT NULL THEN
v_remote_sql := v_remote_sql || ' ' || v_condition || ' AND ';
ELSE
v_remote_sql := v_remote_sql || ' WHERE ';
END IF;
v_remote_sql := v_remote_sql ||format('%I < %L', v_control, v_boundary);
ELSE
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK','Request to repull data from '||COALESCE(p_repull_start, 0)||' to '||COALESCE(p_repull_end, v_boundary));
END IF;
PERFORM gdb(p_debug,'Request to repull data from '||COALESCE(p_repull_start, 0)||' to '||COALESCE(p_repull_end, v_boundary));
v_remote_sql := format('SELECT %s FROM %I.%I', v_cols, v_src_schema_name, v_src_table_name);
IF v_condition IS NOT NULL THEN
v_remote_sql := v_remote_sql || ' ' || v_condition || ' AND ';
ELSE
v_remote_sql := v_remote_sql || ' WHERE ';
END IF;
-- Use upper boundary remote max to avoid edge case of multiple upper boundary values inserting during refresh
v_remote_sql := v_remote_sql || format('%I > %L AND %I < %L'
, v_control
, COALESCE(p_repull_start::bigint, 0)
, v_control
, COALESCE(p_repull_end::bigint, v_boundary));
-- Delete the old local data. Use higher than bigint max upper boundary to ensure all old data is deleted
v_delete_sql := format('DELETE FROM %I.%I WHERE %I > %L AND %I < %L'
, v_dest_schema_name
, v_dest_table_name
, v_control
, COALESCE(p_repull_start::bigint, 0)
, v_control
, COALESCE(p_repull_end::bigint, 9300000000000000000));
IF v_jobmon THEN
v_step_id := add_step(v_job_id, 'Deleting current, local data');
END IF;
PERFORM gdb(p_debug,'Deleting current, local data: '||v_delete_sql);
EXECUTE v_delete_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK', v_rowcount || ' rows removed');
END IF;
END IF;
ELSE
-- does < for upper boundary to keep missing data from happening on rare edge case where a newly inserted row outside the transaction batch
-- has the exact same timestamp as the previous batch's max timestamp
v_remote_sql := format('SELECT %s FROM %I.%I', v_cols, v_src_schema_name, v_src_table_name);
IF v_condition IS NOT NULL THEN
v_remote_sql := v_remote_sql || ' ' || v_condition || ' AND ';
ELSE
v_remote_sql := v_remote_sql || ' WHERE ';
END IF;
v_remote_sql := v_remote_sql || format('%I > %L AND %I < %L ORDER BY %I ASC LIMIT %s'
, v_control
, v_last_value
, v_control
, v_boundary
, v_control
, COALESCE(v_limit::text, 'ALL'));
v_delete_sql := format('DELETE FROM %I.%I a USING mimeo_refresh_updater_temp t WHERE ', v_dest_schema_name, v_dest_table_name);
WHILE v_pk_counter <= array_length(v_pk_name,1) LOOP
IF v_pk_counter > 1 THEN
v_delete_sql := v_delete_sql ||' AND ';
END IF;
v_delete_sql := v_delete_sql ||'a."'||v_pk_name[v_pk_counter]||'" = t."'||v_pk_name[v_pk_counter]||'"';
v_pk_counter := v_pk_counter + 1;
END LOOP;
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK','Grabbing rows from '||v_last_value::text||' to '||v_boundary::text);
END IF;
PERFORM gdb(p_debug,'Grabbing rows from '||v_last_value::text||' to '||v_boundary::text);
END IF;
v_insert_sql := format('INSERT INTO %I.%I (%s) SELECT %s FROM mimeo_refresh_updater_temp', v_dest_schema_name, v_dest_table_name, v_cols, v_cols);
PERFORM gdb(p_debug,v_remote_sql);
-- Ensure name is consistent in case it would get truncated by maximium object name length
v_cursor_name := @extschema@.check_name_length('mimeo_cursor_' || v_src_table_name, p_convert_standard := true);
PERFORM dblink_open(v_dblink_name, v_cursor_name, v_remote_sql);
IF v_jobmon THEN
v_step_id := add_step(v_job_id, 'Inserting new/updated records into local table');
END IF;
v_rowcount := 0;
EXECUTE format('CREATE TEMP TABLE mimeo_refresh_updater_temp (%s)', v_cols_n_types);
LOOP
v_fetch_sql := format('INSERT INTO mimeo_refresh_updater_temp (%s) SELECT %s FROM dblink_fetch(%L, %L, %s) AS (%s)'
, v_cols
, v_cols
, v_dblink_name
, v_cursor_name
, '50000'
, v_cols_n_types);
EXECUTE v_fetch_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
v_total := v_total + coalesce(v_rowcount, 0);
EXECUTE format('SELECT max(%I) FROM mimeo_refresh_updater_temp', v_control) INTO v_last_fetched;
IF v_limit IS NULL OR p_repull IS TRUE THEN -- insert into the real table in batches if no limit or a repull to avoid excessively large temp tables
IF p_repull IS FALSE THEN -- Delete any rows that exist in the current temp table batch. repull delete is done above.
EXECUTE v_delete_sql;
END IF;
EXECUTE v_insert_sql;
TRUNCATE mimeo_refresh_updater_temp;
END IF;
EXIT WHEN v_rowcount = 0;
PERFORM gdb(p_debug,'Fetching rows in batches: '||v_total||' done so far. Last fetched: '||v_last_fetched);
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'PENDING', 'Fetching rows in batches: '||v_total||' done so far. Last fetched: '||v_last_fetched);
END IF;
END LOOP;
PERFORM dblink_close(v_dblink_name, v_cursor_name);
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK','Rows fetched: '||v_total);
END IF;
IF v_limit IS NULL THEN
-- nothing else to do
ELSIF p_repull IS FALSE THEN -- don't care about limits when doing a repull
-- When using batch limits, entire batch must be pulled to temp table before inserting to real table to catch edge cases
IF v_jobmon THEN
v_step_id := add_step(v_job_id,'Checking for batch limit issues');
END IF;
-- Not recommended that the batch actually equal the limit set if possible.
IF v_total >= v_limit THEN
PERFORM gdb(p_debug, 'Row count fetched equal to or greater than limit set: '||v_limit||'. Recommend increasing batch limit if possible.');
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'WARNING','Row count fetched equal to or greater than limit set: '||v_limit||'. Recommend increasing batch limit if possible.');
v_step_id := add_step(v_job_id, 'Removing high boundary rows from this batch to avoid missing data');
END IF;
EXECUTE format('SELECT max(%I) FROM mimeo_refresh_updater_temp', v_control) INTO v_last_value;
EXECUTE format('DELETE FROM mimeo_refresh_updater_temp WHERE %I = %L', v_control, v_last_value);
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK', 'Removed '||v_rowcount||' rows. Batch now contains '||v_limit - v_rowcount||' records');
END IF;
PERFORM gdb(p_debug, 'Removed '||v_rowcount||' rows from batch. Batch table now contains '||v_limit - v_rowcount||' records');
v_batch_limit_reached := 2;
IF (v_limit - v_rowcount) < 1 THEN
IF v_jobmon THEN
v_step_id := add_step(v_job_id, 'Reached inconsistent state');
PERFORM update_step(v_step_id, 'CRITICAL', 'Batch contained max rows ('||v_limit||') or greater and all contained the same timestamp value. Unable to guarentee rows will ever be replicated consistently. Increase row limit parameter to allow a consistent batch.');
END IF;
PERFORM gdb(p_debug, 'Batch contained max rows ('||v_limit||') or greater and all contained the same timestamp value. Unable to guarentee rows will be replicated consistently. Increase row limit parameter to allow a consistent batch.');
v_batch_limit_reached := 3;
END IF;
ELSE
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK','No issues found');
END IF;
PERFORM gdb(p_debug, 'No issues found');
END IF;
IF v_batch_limit_reached <> 3 THEN
EXECUTE format('CREATE INDEX ON mimeo_refresh_updater_temp ("%s")', array_to_string(v_pk_name, '","')); -- incase of large batch limit
ANALYZE mimeo_refresh_updater_temp;
IF v_jobmon THEN
v_step_id := add_step(v_job_id,'Deleting records marked for update in local table');
END IF;
PERFORM gdb(p_debug,v_delete_sql);
EXECUTE v_delete_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK','Deleted '||v_rowcount||' records');
END IF;
IF v_jobmon THEN
v_step_id := add_step(v_job_id,'Inserting new records into local table');
END IF;
perform gdb(p_debug,v_insert_sql);
EXECUTE v_insert_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK','Inserted '||v_rowcount||' records');
END IF;
END IF;
END IF; -- end v_limit IF
IF v_batch_limit_reached <> 3 THEN
IF v_jobmon THEN
v_step_id := add_step(v_job_id, 'Setting next lower boundary');
END IF;
EXECUTE format('SELECT max(%I) FROM %I.%I', v_control, v_dest_schema_name, v_dest_table_name) INTO v_last_value;
UPDATE refresh_config_updater_serial SET last_value = coalesce(v_last_value, 0), last_run = CURRENT_TIMESTAMP WHERE dest_table = p_destination;
IF v_jobmon THEN
PERFORM update_step(v_step_id, 'OK','Lower boundary value is: '||coalesce(v_last_value, 0));
END IF;
PERFORM gdb(p_debug, 'Lower boundary value is: '||coalesce(v_last_value, 0));
END IF;
DROP TABLE IF EXISTS mimeo_refresh_updater_temp;
PERFORM dblink_disconnect(v_dblink_name);
IF v_jobmon THEN
IF v_batch_limit_reached = 0 THEN
PERFORM close_job(v_job_id);
ELSIF v_batch_limit_reached = 2 THEN
-- Set final job status to level 2 (WARNING) to bring notice that the batch limit was reached and may need adjusting.
-- Preventive warning to keep replication from falling behind.
PERFORM fail_job(v_job_id, 2);
ELSIF v_batch_limit_reached = 3 THEN
-- Really bad. Critical alert!
PERFORM fail_job(v_job_id);
END IF;
END IF;
-- Ensure old search path is reset for the current session
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
EXCEPTION
WHEN QUERY_CANCELED THEN
SELECT nspname INTO v_dblink_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'dblink' AND e.extnamespace = n.oid;
EXECUTE format('SELECT %I.dblink_get_connections() @> ARRAY[%L]', v_dblink_schema, v_dblink_name) INTO v_link_exists;
IF v_link_exists THEN
EXECUTE format('SELECT %I.dblink_disconnect(%L)', v_dblink_schema, v_dblink_name);
END IF;
RAISE EXCEPTION '%', SQLERRM;
WHEN OTHERS THEN
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;
SELECT jobmon INTO v_jobmon FROM @extschema@.refresh_config_updater WHERE dest_table = p_destination;
v_jobmon := COALESCE(p_jobmon, v_jobmon);
EXECUTE format('SELECT %I.dblink_get_connections() @> ARRAY[%L]', v_dblink_schema, v_dblink_name) INTO v_link_exists;
IF v_link_exists THEN
EXECUTE format('SELECT %I.dblink_disconnect(%L)', v_dblink_schema, v_dblink_name);
END IF;
IF v_jobmon AND v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NULL THEN
EXECUTE format('SELECT %I.add_job(%L)', v_jobmon_schema, 'Refresh Updater: '||p_destination) INTO v_job_id;
EXECUTE format('SELECT %I.add_step(%L, %L)', v_jobmon_schema, v_job_id, 'EXCEPTION before job logging started') INTO v_step_id;
END IF;
IF v_step_id IS NULL THEN
EXECUTE format('SELECT %I.add_step(%L, %L)', v_jobmon_schema, v_job_id, 'EXCEPTION before first step logged') INTO v_step_id;
END IF;
EXECUTE format('SELECT %I.update_step(%L, %L, %L)', v_jobmon_schema, v_step_id, 'CRITICAL', 'ERROR: '||COALESCE(SQLERRM,'unknown'));
EXECUTE format('SELECT %I.fail_job(%L)', v_jobmon_schema, v_job_id);
END IF;
RAISE EXCEPTION '%', SQLERRM;
END
$$;
|