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
|
CREATE FUNCTION @extschema@.drop_partition_id(
p_parent_table text
, p_retention bigint DEFAULT NULL
, p_keep_table boolean DEFAULT NULL
, p_keep_index boolean DEFAULT NULL
, p_retention_schema text DEFAULT NULL
)
RETURNS int
LANGUAGE plpgsql
AS $$
DECLARE
ex_context text;
ex_detail text;
ex_hint text;
ex_message text;
v_adv_lock boolean;
v_control text;
v_control_type text;
v_count int;
v_drop_count int := 0;
v_index record;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
v_max bigint;
v_new_search_path text;
v_old_search_path text;
v_parent_schema text;
v_parent_tablename text;
v_partition_interval bigint;
v_partition_id bigint;
v_pubname_row record;
v_retention bigint;
v_retention_keep_index boolean;
v_retention_keep_table boolean;
v_retention_keep_publication boolean;
v_retention_schema text;
v_row record;
v_row_max_id record;
v_sql text;
v_step_id bigint;
v_sub_parent text;
BEGIN
/*
* Function to drop child tables from an id-based partition set.
* Options to move table to different schema or actually drop the table from the database.
*/
v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman drop_partition_id'));
IF v_adv_lock = 'false' THEN
RAISE NOTICE 'drop_partition_id already running.';
RETURN 0;
END IF;
IF p_retention IS NULL THEN
SELECT
partition_interval::bigint
, control
, retention::bigint
, retention_keep_table
, retention_keep_index
, retention_keep_publication
, retention_schema
, jobmon
INTO
v_partition_interval
, v_control
, v_retention
, v_retention_keep_table
, v_retention_keep_index
, v_retention_keep_publication
, v_retention_schema
, v_jobmon
FROM @extschema@.part_config
WHERE parent_table = p_parent_table
AND retention IS NOT NULL;
IF v_partition_interval IS NULL THEN
RAISE EXCEPTION 'Configuration for given parent table with a retention period not found: %', p_parent_table;
END IF;
ELSE -- Allow override of configuration options
SELECT
partition_interval::bigint
, control
, retention_keep_table
, retention_keep_index
, retention_keep_publication
, retention_schema
, jobmon
INTO
v_partition_interval
, v_control
, v_retention_keep_table
, v_retention_keep_index
, v_retention_keep_publication
, v_retention_schema
, v_jobmon
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
v_retention := p_retention;
IF v_partition_interval IS NULL THEN
RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
END IF;
END IF;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schema, v_parent_tablename, v_control);
IF v_control_type <> 'id' THEN
RAISE EXCEPTION 'Data type of control column in given partition set is not an integer type';
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');
IF p_keep_table IS NOT NULL THEN
v_retention_keep_table = p_keep_table;
END IF;
IF p_keep_index IS NOT NULL THEN
v_retention_keep_index = p_keep_index;
END IF;
IF p_retention_schema IS NOT NULL THEN
v_retention_schema = p_retention_schema;
END IF;
SELECT schemaname, tablename INTO v_parent_schema, v_parent_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(p_parent_table, '.', 1)::name
AND tablename = split_part(p_parent_table, '.', 2)::name;
-- Loop through child tables starting from highest to get current max value in partition set
-- Avoids doing a scan on entire partition set and/or getting any values accidentally in default.
FOR v_row_max_id IN
SELECT partition_schemaname, partition_tablename FROM @extschema@.show_partitions(p_parent_table, 'DESC')
LOOP
EXECUTE format('SELECT trunc(max(%I)) FROM %I.%I', v_control, v_row_max_id.partition_schemaname, v_row_max_id.partition_tablename) INTO v_max;
IF v_max IS NOT NULL THEN
EXIT;
END IF;
END LOOP;
SELECT sub_parent INTO v_sub_parent FROM @extschema@.part_config_sub WHERE sub_parent = p_parent_table;
-- Loop through child tables of the given parent
-- Must go in ascending order to avoid dropping what may be the "last" partition in the set after dropping tables that match retention period
FOR v_row IN
SELECT partition_schemaname, partition_tablename FROM @extschema@.show_partitions(p_parent_table, 'ASC')
LOOP
SELECT child_start_id INTO v_partition_id FROM @extschema@.show_partition_info(v_row.partition_schemaname||'.'||v_row.partition_tablename
, v_partition_interval::text
, p_parent_table);
-- Add one interval to the start of the constraint period
RAISE DEBUG 'drop_partition_id: v_retention: %, v_max: %, v_partition_id: %, v_partition_interval: %', v_retention, v_max, v_partition_id, v_partition_interval;
IF v_retention <= (v_max - (v_partition_id + v_partition_interval)) THEN
-- Do not allow final partition to be dropped if it is not a sub-partition parent
SELECT count(*) INTO v_count FROM @extschema@.show_partitions(p_parent_table);
IF v_count = 1 AND v_sub_parent IS NULL THEN
RAISE WARNING 'Attempt to drop final partition in partition set % as part of retention policy. If you see this message multiple times for the same table, advise reviewing retention policy and/or data entry into the partition set. Also consider setting "infinite_time_partitions = true" if there are large gaps in data insertion.', p_parent_table;
CONTINUE;
END IF;
-- Only create a jobmon entry if there's actual retention work done
IF v_jobmon_schema IS NOT NULL AND v_job_id IS NULL THEN
v_job_id := add_job(format('PARTMAN DROP ID PARTITION: %s', p_parent_table));
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Detach/Uninherit table %s.%s from %s', v_row.partition_schemaname, v_row.partition_tablename, p_parent_table));
END IF;
IF v_retention_keep_table = true OR v_retention_schema IS NOT NULL THEN
-- No need to detach partition before dropping since it's going away anyway
-- TODO Review this to see how to handle based on recent FK issues
-- Avoids issue of FKs not allowing detachment (Github Issue #294).
v_sql := format('ALTER TABLE %I.%I DETACH PARTITION %I.%I'
, v_parent_schema
, v_parent_tablename
, v_row.partition_schemaname
, v_row.partition_tablename);
EXECUTE v_sql;
IF v_retention_keep_index = false THEN
FOR v_index IN
WITH child_info AS (
SELECT c1.oid
FROM pg_catalog.pg_class c1
JOIN pg_catalog.pg_namespace n1 ON c1.relnamespace = n1.oid
WHERE c1.relname = v_row.partition_tablename::name
AND n1.nspname = v_row.partition_schemaname::name
)
SELECT c.relname as name
, con.conname
FROM pg_catalog.pg_index i
JOIN pg_catalog.pg_class c ON i.indexrelid = c.oid
LEFT JOIN pg_catalog.pg_constraint con ON i.indexrelid = con.conindid
JOIN child_info ON i.indrelid = child_info.oid
LOOP
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Drop index %s from %s.%s'
, v_index.name
, v_row.partition_schemaname
, v_row.partition_tablename));
END IF;
IF v_index.conname IS NOT NULL THEN
EXECUTE format('ALTER TABLE %I.%I DROP CONSTRAINT %I', v_row.partition_schemaname, v_row.partition_tablename, v_index.conname);
ELSE
EXECUTE format('DROP INDEX %I.%I', v_row.partition_schemaname, v_index.name);
END IF;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END LOOP;
END IF; -- end v_retention_keep_index IF
-- Remove table from publication(s) if desired
IF v_retention_keep_publication = false THEN
FOR v_pubname_row IN
SELECT p.pubname
FROM pg_catalog.pg_publication_rel pr
JOIN pg_catalog.pg_publication p ON p.oid = pr.prpubid
JOIN pg_catalog.pg_class c ON c.oid = pr.prrelid
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE n.nspname = v_row.partition_schemaname
AND c.relname = v_row.partition_tablename
LOOP
EXECUTE format('ALTER PUBLICATION %I DROP TABLE %I.%I', v_pubname_row.pubname, v_row.partition_schemaname, v_row.partition_tablename);
END LOOP;
END IF;
END IF;
IF v_retention_schema IS NULL THEN
IF v_retention_keep_table = false THEN
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Drop table %s.%s', v_row.partition_schemaname, v_row.partition_tablename));
END IF;
v_sql := 'DROP TABLE %I.%I';
EXECUTE format(v_sql, v_row.partition_schemaname, v_row.partition_tablename);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END IF;
ELSE -- Move to new schema
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Moving table %s.%s to schema %s'
, v_row.partition_schemaname
, v_row.partition_tablename
, v_retention_schema));
END IF;
EXECUTE format('ALTER TABLE %I.%I SET SCHEMA %I'
, v_row.partition_schemaname
, v_row.partition_tablename
, v_retention_schema);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END IF; -- End retention schema if
-- If child table is a subpartition, remove it from part_config & part_config_sub (should cascade due to FK)
DELETE FROM @extschema@.part_config WHERE parent_table = v_row.partition_schemaname ||'.'||v_row.partition_tablename;
v_drop_count := v_drop_count + 1;
END IF; -- End retention check IF
END LOOP; -- End child table loop
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Finished partition drop maintenance');
PERFORM update_step(v_step_id, 'OK', format('%s partitions dropped.', v_drop_count));
PERFORM close_job(v_job_id);
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_drop_count;
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 DROP ID PARTITION: %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
$$;
|