├── LICENSE ├── META.json ├── Makefile ├── README.md ├── doc └── changelog.md ├── recursively_delete.control ├── sql ├── recursively_delete.sql └── uninstall_recursively_delete.sql └── test ├── expected ├── install.out └── uninstall.out └── sql ├── install.sql └── uninstall.sql /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2019-2021 trlorenz 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "recursively_delete", 3 | "abstract": "Delete records and foreign-key dependents, regardless of constraint type", 4 | "description": "A long description", 5 | "version": "0.1.5", 6 | "maintainer": "", 7 | "license": "MIT", 8 | "provides": { 9 | "recursively_delete": { 10 | "abstract": "Delete records and foreign-key dependents, regardless of constraint type", 11 | "file": "sql/recursively_delete.sql", 12 | "docfile": "doc/recursively_delete.md", 13 | "version": "0.1.5" 14 | } 15 | }, 16 | "release_status": "unstable", 17 | 18 | "generated_by": "", 19 | 20 | 21 | "tags": [ "DELETE","CASCADE" ], 22 | 23 | "meta-spec": { 24 | "version": "1.0.0", 25 | "url": "http://pgxn.org/meta/spec.txt" 26 | } 27 | } 28 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = recursively_delete 2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 3 | 4 | DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql)) 5 | DOCS = $(wildcard doc/*.md) 6 | TESTS = $(wildcard test/sql/*.sql) 7 | REGRESS = install \ 8 | uninstall 9 | REGRESS_OPTS = --inputdir=test 10 | 11 | PG_CONFIG = pg_config 12 | 13 | all: sql/$(EXTENSION)--$(EXTVERSION).sql 14 | 15 | sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql 16 | cp $< $@ 17 | 18 | DATA = $(wildcard sql/*--*.sql) 19 | EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql 20 | 21 | PGXS := $(shell $(PG_CONFIG) --pgxs) 22 | include $(PGXS) 23 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PG-recursively_delete 2 | 3 | Delete records and foreign-key dependents, regardless of constraint type. 4 | 5 | - Provides an ASCII preview of the deletion target and its graph of dependents. 6 | - Performs deletion in a single query using recursive CTEs. 7 | - Handles circular dependencies, intra- and inter-table. 8 | - Handles composite keys. 9 | - Skips 'set default' and 'set null' constraints. 10 | 11 | ### Disclaimers 12 | 13 | - Obviously, use recursively_delete at your own risk. Test it on non-crucial data before using it in production to gain a degree of confidence with it. **Make backups.** This software purposely destroys data and is not guaranteed bug-free. 14 | 15 | - recursively_delete was written not for transactional use-cases, but as an administration tool for special occasions. Performance wasn't the main consideration. 16 | 17 | - recursively_delete was developed for PostgreSQL 10.10. It might work for other versions; it might not. (Feedback is welcome!) UPDATE 2020-12-17: Been using recursively_delete on PG 13.1 for some months, now, with no issues. 18 | 19 | ### Installation 20 | 21 | * Clone. 22 | 23 | * `cd recursively_delete/` 24 | 25 | * `make` 26 | 27 | * `make install` (or `sudo make install`) 28 | 29 | * Log into your DB and `create extension recursively_delete;` 30 | 31 | ### Signature 32 | 33 | ```PLpgSQL 34 | recursively_delete( 35 | ARG_table REGCLASS , 36 | ARG_in ANYELEMENT , 37 | ARG_for_realz BOOL DEFAULT FALSE 38 | ) RETURNS INT 39 | ``` 40 | 41 | ##### ARG_table 42 | 43 | The table from which you'll be deleting records, with or without a qualifying schema. 44 | 45 | ##### ARG_in 46 | 47 | A specifier for the records you'll be deleting. Loosely speaking, this would be something that'd work in an IN clause like so: 48 | 49 | ```PLpgSQL 50 | ...WHERE my_table.primary_key IN (ARG_in)... 51 | ``` 52 | 53 | Possibilities include: 54 | 55 | - An integer: 22 56 | - An array of integers: ARRAY[22, 33, 44] 57 | - A string: 'foo'::TEXT 58 | - An array of strings: ARRAY['foo', 'bar', 'baz'] 59 | - A uuid: '12345678-90ab-cdef-1234-567890abcdef'::UUID 60 | - An array of uuids: ARRAY['12345678-90ab-cdef-1234-567890abcdef', '12345678-90ab-cdef-1234-567890abcdef', '12345678-90ab-cdef-1234-567890abcdef'] 61 | - For [composite keys](#delete-three-records-on-a-composite-primary-key), an array of arrays: 62 | - ARRAY[[22, 33], [44, 55], [66, 77]] 63 | - ARRAY[['22', 'foo'], ['33', 'bar'], ['44', 'baz']] 64 | - A subquery returning one of the above: 65 | - (SELECT array_agg(id) FROM my_table WHERE on_the_chopping_block = true) 66 | - (SELECT array_agg(ARRAY[id1::TEXT, id2::TEXT, id3::TEXT]) FROM my_table WHERE on_the_chopping_block = true) 67 | 68 | *Note that since ANYELEMENT considers untyped text to be type-ambiguous, it's necessary to explicitly type any text value given for ARG_in (e.g. 'foo'::TEXT). Otherwise brace yourself for something like 'ERROR: could not determine polymorphic type because input has type unknown'.* 69 | 70 | ##### ARG_for_realz 71 | 72 | When false, instructs recursively_delete **not** to delete any records, but instead produce an ASCII representation of the graph of records that **would** be deleted if ARG_for_realz were true. It's false by default. 73 | 74 | *Be advised that previews are calculated by running **actual deletions** in a transaction that's ultimately rolled back.* 75 | 76 | ##### Return value 77 | 78 | recursively_delete returns the number of records **explicitly** deleted (not including the records implicitly deleted pursuant to foreign key dependency). When ARG_for_realz is false, recursively_delete always returns zero. 79 | 80 | ### Examples 81 | 82 | ##### Preview the deletion of a single record: 83 | 84 | ```PLpgSQL 85 | -- Clobber noisy context in output: 86 | 87 | \set VERBOSITY terse 88 | 89 | -- Then... 90 | 91 | select recursively_delete('users', 4402); 92 | 93 | -- ...or: 94 | 95 | select recursively_delete('users', 4402, false); 96 | ``` 97 | 98 | ``` 99 | INFO: 1 users 100 | INFO: 4 a | ad_submissions.["user_id"] 101 | INFO: 182 a | broadcasts.["created_by"] 102 | INFO: 512 c | | channel_selections.["broadcast_id"] 103 | INFO: 0 c | | post_approvals.["broadcast_id"] 104 | INFO: 1 c | | post_rejections.["broadcast_id"] 105 | INFO: 326 c | | recipient_selections.["broadcast_id"] 106 | INFO: 309 c ∞ | | subchannel_statuses.["broadcast_id"] 107 | INFO: 293 a ∞ | | | engagements.["subchannel_status_id"] 108 | INFO: 245 c ∞ | | | | conversations.["engagement_id"] 109 | INFO: 0 a ∞ | | | | | broadcasts.["conversation_id"] 110 | INFO: 0 c | | | | | | channel_selections.["broadcast_id"] 111 | INFO: 0 c | | | | | | post_approvals.["broadcast_id"] 112 | INFO: 0 c | | | | | | post_rejections.["broadcast_id"] 113 | INFO: 0 c | | | | | | recipient_selections.["broadcast_id"] 114 | INFO: 0 a ∞ | | | | | engagements.["parent_conversation_id"] 115 | INFO: 94 c | | | | | interaction_updates.["conversation_id"] 116 | INFO: ~ n | broadcasts.["edited_by"] 117 | INFO: 0 a | engagements.["user_id"] 118 | INFO: 0 c ∞ | | conversations.["engagement_id"] 119 | INFO: 0 a ∞ | | | broadcasts.["conversation_id"] 120 | 121 | ...etc., abridged (this was a big graph)... 122 | 123 | recursively_delete 124 | -------------------- 125 | 0 126 | (1 row) 127 | 128 | ``` 129 | 130 | The first three columns are, at each given node: 131 | 132 | 1. The number of records to be deleted. ('~' indicates that no deletion will be attempted at the node on account of a 'set default' or 'set null' constraint.) 133 | 2. The FK constraint type: one of 'a', 'r', 'c', 'n', or 'd' ('no action', 'restrict', 'cascade', 'set null', or 'set default'). 134 | 3. An indicator of participation in a circular dependency. 135 | 136 | 137 | The graph indicates affected tables and how each relates to its parent vis-à-vis the deletion operation. For example, at the top of the graph above, one *user* record would be deleted. As a result of this, four *ad_submissions* records would be deleted because of a 'no action' constraint on the *ad_submissions.user_id* column relating to *users*; and 182 *broadcasts* records would be deleted because of a 'no action' constraint on the *broadcasts.created_by* column relating to *users*; and 512 *channel_selections* records would be deleted because of a 'cascade' constraint on the *channel_selections.broadcast_id* column relating to *broadcasts*; and so on. 138 | 139 | ##### Go ahead and delete that single record: 140 | 141 | ```PLpgSQL 142 | select recursively_delete('users', 4402, true); 143 | ``` 144 | 145 | ``` 146 | recursively_delete 147 | -------------------- 148 | 1 149 | (1 row) 150 | ``` 151 | 152 | ##### Delete three records on a composite primary key: 153 | 154 | ```PLpgSQL 155 | select recursively_delete('widgets', ARRAY[['foo', '22'], ['bar', '33'], ['baz', '44']], true); 156 | ``` 157 | 158 | ``` 159 | recursively_delete 160 | -------------------- 161 | 3 162 | (1 row) 163 | ``` 164 | 165 | *Note that the order of the key columns in each subarray above isn't arbitrary; recursively_delete assumes composite key columns are given in the same order as they were given in the applicable index definition (using pg_index.indkey_subscript).* 166 | 167 | *Note also that, in this contrived example, the types of the columns of the composite primary key are TEXT and INTEGER. Since the elements of a Postgres Array must be of a consistent type, a situation like this calls for using untyped text elements; Postgres will perform the necessary coercions.* 168 | -------------------------------------------------------------------------------- /doc/changelog.md: -------------------------------------------------------------------------------- 1 | v0.1.5 - 2021-04-22 2 | 3 | * Added explicit support for BIGINT keys. 4 | 5 | v0.1.4 - 2021-04-22 6 | 7 | * Extensionized. Thanks to David Fetter. 8 | 9 | v0.1.3 - 2021-04-20 10 | 11 | * Removed `ORDER BY` from view. 12 | 13 | v0.1.2 - 2020-12-31 14 | 15 | * Fixed borked CTE aux statement being generated when VAR_in resolves to NULL or an empty STRING. 16 | 17 | v0.1.1 - 2020-12-17 18 | 19 | * Fixed borked CTE aux statement being generated when VAR_in resolves to empty ARRAY. 20 | * Added a header to the preview, to display the recursively_delete version. 21 | 22 | v0.1.0 - 2020-06-030 23 | 24 | * Added explicit support for UUID keys. 25 | * Breaking change: Removed ability to pass an SQL string for the ARG_in parameter. An actual 26 | subquery serves the purpose better and without ambiguity. 27 | 28 | v0.0.0 - < 2020-06-30 29 | -------------------------------------------------------------------------------- /recursively_delete.control: -------------------------------------------------------------------------------- 1 | # recursively_delete extension 2 | comment = 'Delete records and foreign-key dependents, regardless of constraint type' 3 | default_version = '0.1.5' 4 | relocatable = true 5 | -------------------------------------------------------------------------------- /sql/recursively_delete.sql: -------------------------------------------------------------------------------- 1 | \echo Use "CREATE EXTENSION recursively_delete" to load this file. \quit 2 | 3 | SET client_min_messages = warning; 4 | 5 | CREATE VIEW v_fk_cons AS 6 | WITH 7 | fk_constraints AS ( 8 | SELECT 9 | pg_constraint.oid, 10 | pg_constraint.conname AS name, 11 | pg_constraint.confdeltype AS delete_action, 12 | pg_constraint.conrelid, 13 | pg_constraint.confrelid, 14 | pg_constraint.conkey, 15 | pg_constraint.confkey, 16 | pg_ns_tcon.nspname AS ctab_schema_name, 17 | pg_class_tcon.relname AS ctab_name, 18 | pg_ns_trel.nspname AS ptab_schema_name, 19 | pg_class_trel.relname AS ptab_name 20 | FROM 21 | pg_constraint, pg_namespace pg_ns_tcon, pg_class pg_class_tcon, 22 | pg_namespace pg_ns_trel, pg_class pg_class_trel 23 | WHERE 24 | pg_constraint.conrelid = pg_class_tcon.oid AND pg_class_tcon.relnamespace = pg_ns_tcon.oid 25 | AND 26 | pg_constraint.confrelid = pg_class_trel.oid AND pg_class_trel.relnamespace = pg_ns_trel.oid 27 | AND 28 | pg_constraint.contype = 'f'::CHAR 29 | ), 30 | ctab_pk_attrs AS ( 31 | SELECT 32 | fk_constraints.oid, 33 | array_agg(pg_attribute.attname ORDER BY pg_index.indkey_subscript) AS ctab_pk_col_names, 34 | array_agg(format_type(pg_attribute.atttypid, pg_attribute.atttypmod) ORDER BY pg_index.indkey_subscript) AS ctab_pk_col_types 35 | FROM 36 | fk_constraints 37 | INNER JOIN 38 | pg_attribute 39 | ON 40 | fk_constraints.conrelid = pg_attribute.attrelid 41 | INNER JOIN 42 | (SELECT *, generate_subscripts(indkey, 1) AS indkey_subscript FROM pg_index) AS pg_index 43 | ON 44 | pg_attribute.attrelid = pg_index.indrelid AND pg_attribute.attnum = pg_index.indkey[pg_index.indkey_subscript] 45 | AND 46 | pg_index.indisprimary 47 | GROUP BY 48 | fk_constraints.oid 49 | ), 50 | ctab_fk_attrs AS ( 51 | SELECT 52 | fk_constraints.oid, 53 | array_agg(pg_attribute.attname ORDER BY fk_constraints.conkey_subscript) AS ctab_fk_col_names, 54 | array_agg(format_type(pg_attribute.atttypid, pg_attribute.atttypmod) ORDER BY fk_constraints.conkey_subscript) AS ctab_fk_col_types 55 | FROM 56 | pg_attribute 57 | INNER JOIN 58 | (SELECT *, generate_subscripts(fk_constraints.conkey, 1) AS conkey_subscript FROM fk_constraints) AS fk_constraints 59 | ON 60 | pg_attribute.attrelid = fk_constraints.conrelid AND pg_attribute.attnum = fk_constraints.conkey[fk_constraints.conkey_subscript] 61 | GROUP BY 62 | fk_constraints.oid 63 | ), 64 | ptab_uk_attrs AS ( 65 | SELECT 66 | fk_constraints.oid, 67 | array_agg(pg_attribute.attname ORDER BY fk_constraints.confkey_subscript) AS ptab_uk_col_names, 68 | array_agg(format_type(pg_attribute.atttypid, pg_attribute.atttypmod) ORDER BY fk_constraints.confkey_subscript) AS ptab_uk_col_types 69 | FROM 70 | pg_attribute 71 | INNER JOIN 72 | (SELECT *, generate_subscripts(fk_constraints.confkey, 1) AS confkey_subscript FROM fk_constraints) AS fk_constraints 73 | ON 74 | pg_attribute.attrelid = fk_constraints.confrelid AND pg_attribute.attnum = fk_constraints.confkey[fk_constraints.confkey_subscript] 75 | GROUP BY 76 | fk_constraints.oid 77 | ) 78 | SELECT 79 | fk_constraints.oid, 80 | fk_constraints.name, 81 | fk_constraints.delete_action, 82 | fk_constraints.conrelid AS ctab_oid, 83 | fk_constraints.ctab_schema_name, 84 | fk_constraints.ctab_name, 85 | ctab_pk_attrs.ctab_pk_col_names, 86 | ctab_pk_attrs.ctab_pk_col_types, 87 | ctab_fk_attrs.ctab_fk_col_names, 88 | ctab_fk_attrs.ctab_fk_col_types, 89 | fk_constraints.confrelid AS ptab_oid, 90 | fk_constraints.ptab_schema_name, 91 | fk_constraints.ptab_name, 92 | ptab_uk_attrs.ptab_uk_col_names, 93 | ptab_uk_attrs.ptab_uk_col_types 94 | FROM fk_constraints 95 | INNER JOIN ctab_pk_attrs USING (oid) 96 | INNER JOIN ctab_fk_attrs USING (oid) 97 | INNER JOIN ptab_uk_attrs USING (oid); 98 | 99 | CREATE FUNCTION _recursively_delete( 100 | ARG_table REGCLASS , 101 | ARG_pk_col_names TEXT[] , 102 | _ARG_depth INT DEFAULT 0 , 103 | _ARG_fk_con JSONB DEFAULT NULL , 104 | _ARG_flat_graph_i_up INT DEFAULT NULL , 105 | _ARG_path TEXT[] DEFAULT ARRAY[]::TEXT[], 106 | INOUT _ARG_circ_deps JSONB DEFAULT '[]' , 107 | INOUT _ARG_flat_graph JSONB DEFAULT '[]' 108 | ) 109 | LANGUAGE plpgsql 110 | AS $$ 111 | DECLARE 112 | VAR_circ_dep JSONB ; 113 | VAR_ctab_fk_col_names JSONB ; 114 | VAR_ctab_pk_col_names JSONB ; 115 | VAR_fk_con_rec RECORD; 116 | VAR_flat_graph_i INT ; 117 | VAR_flat_graph_node JSONB ; 118 | VAR_i INT ; 119 | VAR_path_pos_of_oid INT ; 120 | BEGIN 121 | IF _ARG_depth = 0 THEN 122 | _ARG_path := _ARG_path || ARRAY['ROOT']; 123 | 124 | VAR_ctab_pk_col_names := array_to_json(ARG_pk_col_names)::JSONB; 125 | 126 | -- Not really a statement of truth, but a convenient thing to pretend. For the initial 127 | -- "bootstrap" CTE auxiliary statement, this HACK takes care of equating the user's ARG_in with 128 | -- the table's primary key. 129 | VAR_ctab_fk_col_names := VAR_ctab_pk_col_names; 130 | ELSE 131 | VAR_ctab_fk_col_names := _ARG_fk_con->>'ctab_fk_col_names'; 132 | VAR_ctab_pk_col_names := _ARG_fk_con->>'ctab_pk_col_names'; 133 | END IF; 134 | 135 | VAR_flat_graph_i := jsonb_array_length(_ARG_flat_graph); 136 | 137 | -- The "flat graph" is a collection of foreign-key-constraint-describing objects ("nodes") 138 | -- arranged in correct order for composition of the final query. 139 | 140 | -- (Note that while flat_graph_node->>'i' always reports the index of a flat graph node in the 141 | -- flat graph, flat_graph_node->>'i_up' reports the index of the node's parent, which isn't 142 | -- necessarily i - 1.) 143 | _ARG_flat_graph := _ARG_flat_graph || jsonb_build_object( 144 | 'ctab_fk_col_names', VAR_ctab_fk_col_names, 145 | 'ctab_name' , ARG_table, 146 | 'ctab_oid' , _ARG_fk_con->>'ctab_oid', 147 | 'ctab_pk_col_names', VAR_ctab_pk_col_names, 148 | 'cte_aux_stmt_name', format('del_%s$%s', VAR_flat_graph_i, _ARG_path[array_upper(_ARG_path, 1)]), 149 | 'delete_action' , _ARG_fk_con->>'delete_action', 150 | 'depth' , _ARG_depth, 151 | 'i' , VAR_flat_graph_i, 152 | 'i_up' , _ARG_flat_graph_i_up, 153 | 'path' , array_to_json(_ARG_path)::JSONB, 154 | 'ptab_uk_col_names', _ARG_fk_con->'ptab_uk_col_names' 155 | ); 156 | 157 | IF _ARG_fk_con->>'delete_action' IN ('d', 'n') THEN 158 | RETURN; 159 | END IF; 160 | 161 | <> 162 | FOR VAR_fk_con_rec IN (SELECT * FROM v_fk_cons WHERE ptab_oid = ARG_table ORDER BY name) LOOP 163 | VAR_path_pos_of_oid := array_position(_ARG_path, VAR_fk_con_rec.oid::TEXT); 164 | 165 | IF VAR_path_pos_of_oid IS NOT NULL THEN 166 | --^ If the id of the foreign key constraint already exists in the current path, we know the 167 | -- constraint is the beginning (ending?) of a circular dependency. 168 | 169 | VAR_circ_dep := '[]'; 170 | 171 | -- Populate VAR_circ_dep with the interdependent queue elements comprising the circle (which 172 | -- we'll call "deppers"). 173 | FOR VAR_i IN VAR_path_pos_of_oid .. array_length(_ARG_path, 1) LOOP 174 | FOR VAR_flat_graph_node IN SELECT jsonb_array_elements(_ARG_flat_graph) LOOP 175 | IF VAR_flat_graph_node->'path' = array_to_json(_ARG_path[1:VAR_i])::JSONB THEN 176 | VAR_circ_dep := VAR_circ_dep || VAR_flat_graph_node; 177 | 178 | EXIT; 179 | END IF; 180 | END LOOP; 181 | END LOOP; 182 | 183 | -- Make the first depper in the circle think its parent is the last depper in the circle. 184 | VAR_circ_dep := jsonb_set(VAR_circ_dep, ARRAY['0', 'i_up'], VAR_circ_dep->-1->'i'); 185 | 186 | _ARG_circ_deps := _ARG_circ_deps || jsonb_build_array(VAR_circ_dep); 187 | 188 | CONTINUE FK_CON; 189 | END IF; 190 | 191 | SELECT * INTO _ARG_circ_deps, _ARG_flat_graph 192 | FROM _recursively_delete( 193 | format('%I.%I', VAR_fk_con_rec.ctab_schema_name, VAR_fk_con_rec.ctab_name), 194 | NULL, 195 | -- 196 | _ARG_depth + 1, 197 | row_to_json(VAR_fk_con_rec)::JSONB, 198 | VAR_flat_graph_i, 199 | _ARG_path || VAR_fk_con_rec.oid::TEXT, 200 | -- 201 | _ARG_circ_deps, 202 | _ARG_flat_graph 203 | ); 204 | END LOOP; 205 | END; 206 | $$; 207 | 208 | DROP FUNCTION IF EXISTS recursively_delete; 209 | 210 | CREATE FUNCTION recursively_delete( 211 | ARG_table REGCLASS , 212 | ARG_in ANYELEMENT , 213 | ARG_for_realz BOOL DEFAULT FALSE 214 | ) RETURNS integer 215 | LANGUAGE plpgsql 216 | AS $$ 217 | DECLARE 218 | VAR_version TEXT DEFAULT '0.1.5' ; 219 | -- 220 | VAR_circ_dep JSONB ; 221 | VAR_circ_depper JSONB ; 222 | VAR_circ_depper_up JSONB ; 223 | VAR_circ_deps JSONB ; 224 | VAR_ctab_fk_cols_list TEXT ; 225 | VAR_ctab_pk_cols_list TEXT ; 226 | VAR_cte_aux_stmts TEXT[] DEFAULT ARRAY[]::TEXT[]; 227 | VAR_del_result_rec RECORD ; 228 | VAR_del_results JSONB DEFAULT '{}' ; 229 | VAR_del_results_cursor REFCURSOR ; 230 | VAR_final_query TEXT ; 231 | VAR_flat_graph JSONB ; 232 | VAR_flat_graph_node JSONB ; 233 | VAR_in TEXT ; 234 | VAR_join_comperand_l TEXT ; 235 | VAR_join_comperand_r TEXT ; 236 | VAR_pk_col_names TEXT[] DEFAULT ARRAY[]::TEXT[]; 237 | VAR_recursive_term TEXT ; 238 | VAR_recursive_term_from TEXT[] ; 239 | VAR_recursive_term_select TEXT[] ; 240 | VAR_recursive_term_where TEXT[] ; 241 | VAR_selects_for_union TEXT[] ; 242 | BEGIN 243 | -- ... 244 | SELECT array_agg(pg_attribute.attname ORDER BY pg_index.indkey_subscript) AS ptab_pk_col_names INTO VAR_pk_col_names 245 | FROM 246 | pg_attribute 247 | INNER JOIN 248 | (SELECT *, generate_subscripts(indkey, 1) AS indkey_subscript FROM pg_index) AS pg_index 249 | ON 250 | pg_attribute.attrelid = pg_index.indrelid AND pg_attribute.attnum = pg_index.indkey[pg_index.indkey_subscript] 251 | AND 252 | pg_index.indisprimary 253 | WHERE 254 | pg_attribute.attrelid = ARG_table; 255 | 256 | IF array_length(VAR_pk_col_names, 1) = 1 THEN 257 | CASE pg_typeof(ARG_in)::TEXT 258 | WHEN 'character varying', 'text', 'uuid' THEN 259 | VAR_in := format('%L', ARG_in); 260 | WHEN 'character varying[]', 'text[]', 'uuid[]' THEN 261 | VAR_in := string_agg(format('%L', ael), ', ') FROM unnest(ARG_in) ael; 262 | WHEN 'bigint', 'integer' THEN 263 | VAR_in := ARG_in; 264 | WHEN 'bigint[]', 'integer[]' THEN 265 | VAR_in := array_to_string(ARG_in, ', '); 266 | ELSE 267 | RAISE 'ARG_in "%" is of an unexpected type: %', ARG_in, pg_typeof(ARG_in); 268 | END CASE; 269 | ELSE 270 | CASE pg_typeof(ARG_in)::TEXT 271 | WHEN 'character varying[]', 'text[]', 'uuid[]' THEN 272 | IF array_ndims(ARG_in) = 1 THEN 273 | VAR_in := format('(%s)', (SELECT string_agg(format('%L', ael), ', ') FROM unnest(ARG_in) ael)); 274 | ELSE 275 | VAR_in := string_agg(format('(%s)', (SELECT string_agg(format('%L', ael), ', ') FROM jsonb_array_elements_text(ael) ael)), ', ') FROM jsonb_array_elements(array_to_json(ARG_in)::JSONB) ael; 276 | END IF; 277 | WHEN 'bigint[]', 'integer[]' THEN 278 | IF array_ndims(ARG_in) = 1 THEN 279 | VAR_in := format('(%s)', array_to_string(ARG_in, ', ')); 280 | ELSE 281 | VAR_in := string_agg(format('(%s)', (SELECT string_agg(ael, ', ') FROM jsonb_array_elements_text(ael) ael)), ', ') FROM jsonb_array_elements(array_to_json(ARG_in)::JSONB) ael; 282 | END IF; 283 | ELSE 284 | RAISE 'ARG_in "%" for %-column primary key is of an unexpected type: %', ARG_in, array_length(VAR_pk_col_names, 1), pg_typeof(ARG_in); 285 | END CASE; 286 | END IF; 287 | 288 | IF (VAR_in IS NULL OR VAR_in = '') THEN 289 | VAR_in := 'NULL'; 290 | END IF; 291 | 292 | SELECT * INTO VAR_circ_deps, VAR_flat_graph FROM _recursively_delete(ARG_table, VAR_pk_col_names); 293 | 294 | FOR VAR_flat_graph_node IN SELECT jsonb_array_elements(VAR_flat_graph) LOOP 295 | IF VAR_flat_graph_node->>'delete_action' IN ('d', 'n') THEN 296 | VAR_cte_aux_stmts := VAR_cte_aux_stmts || format('%I AS (SELECT NULL)', VAR_flat_graph_node->>'cte_aux_stmt_name'); 297 | ELSE 298 | VAR_recursive_term := NULL; 299 | 300 | IF (VAR_flat_graph_node->>'depth')::INT != 0 THEN 301 | -- ^The root CTE aux statement is never allowed to be recursive. 302 | 303 | <> 304 | FOR VAR_circ_dep IN SELECT jsonb_array_elements(VAR_circ_deps) LOOP 305 | IF VAR_flat_graph_node->>'i' IN (SELECT jsonb_array_elements(VAR_circ_dep)->>'i') THEN 306 | VAR_recursive_term_from := ARRAY[]::TEXT[]; 307 | VAR_recursive_term_where := ARRAY[]::TEXT[]; 308 | 309 | VAR_recursive_term_select := array_agg(format('%I.%I', format('t%s', VAR_flat_graph_node->>'i'), ael)) 310 | FROM jsonb_array_elements_text(VAR_flat_graph_node->'ctab_pk_col_names') ael; 311 | 312 | FOR VAR_circ_depper IN SELECT * FROM jsonb_array_elements(VAR_circ_dep) LOOP 313 | VAR_recursive_term_from := VAR_recursive_term_from || format('%s %I', 314 | VAR_circ_depper->>'ctab_name', format('t%s', VAR_circ_depper->>'i') 315 | ); 316 | 317 | VAR_join_comperand_l := string_agg(format('%I.%I', format('t%s', VAR_circ_depper->>'i'), ael), ', ') 318 | FROM jsonb_array_elements_text(VAR_circ_depper->'ctab_fk_col_names') ael; 319 | 320 | VAR_circ_depper_up := VAR_flat_graph->((VAR_circ_depper->>'i_up')::INT); 321 | 322 | IF VAR_flat_graph_node->>'ctab_oid' = VAR_circ_depper_up->>'ctab_oid' THEN 323 | VAR_join_comperand_r := string_agg(format('self_ref.%I', ael), ', ') 324 | FROM jsonb_array_elements_text(VAR_flat_graph_node->'ctab_pk_col_names') ael; 325 | ELSE 326 | VAR_join_comperand_r := string_agg(format('%I.%I', format('t%s', VAR_circ_depper_up->>'i'), ael), ', ') 327 | FROM jsonb_array_elements_text(VAR_circ_depper_up->'ctab_pk_col_names') ael; 328 | END IF; 329 | 330 | VAR_recursive_term_where := VAR_recursive_term_where || format('(%s) = (%s)', VAR_join_comperand_l, VAR_join_comperand_r); 331 | END LOOP; 332 | 333 | VAR_recursive_term_from := VAR_recursive_term_from || ARRAY['self_ref']; 334 | 335 | VAR_recursive_term := format('SELECT %s FROM %s WHERE %s', 336 | array_to_string(VAR_recursive_term_select, ', '), 337 | array_to_string(VAR_recursive_term_from, ', '), 338 | array_to_string(VAR_recursive_term_where , ' AND ') 339 | ); 340 | 341 | EXIT LOOP_BUILDING_RECURSIVE_TERM; 342 | END IF; 343 | END LOOP; 344 | END IF; 345 | 346 | VAR_ctab_fk_cols_list := string_agg(format('%I', ael), ', ') FROM jsonb_array_elements_text(VAR_flat_graph_node->'ctab_fk_col_names') ael; 347 | VAR_ctab_pk_cols_list := string_agg(format('%I', ael), ', ') FROM jsonb_array_elements_text(VAR_flat_graph_node->'ctab_pk_col_names') ael; 348 | 349 | IF (VAR_flat_graph_node->>'depth')::INT != 0 THEN 350 | VAR_in := format('SELECT %s FROM %I', 351 | (SELECT string_agg(format('%I', ael), ', ') FROM jsonb_array_elements_text(VAR_flat_graph_node->'ptab_uk_col_names') ael), 352 | VAR_flat_graph->((VAR_flat_graph_node->>'i_up')::INT)->>'cte_aux_stmt_name' 353 | ); 354 | END IF; 355 | 356 | VAR_recursive_term := coalesce(VAR_recursive_term, format('SELECT %s', array_to_string(array_fill('NULL'::TEXT, ARRAY[jsonb_array_length(VAR_flat_graph_node->'ctab_pk_col_names')]), ', '))); 357 | 358 | VAR_cte_aux_stmts := VAR_cte_aux_stmts || format($CTE_AUX_STMT$ 359 | %I AS ( 360 | DELETE FROM %s WHERE (%s) IN ( 361 | WITH RECURSIVE 362 | self_ref (%s) AS ( 363 | SELECT %s FROM %s WHERE (%s) IN (%s) 364 | UNION 365 | %s 366 | ) 367 | SELECT %s FROM self_ref 368 | ) RETURNING * 369 | ) 370 | $CTE_AUX_STMT$, 371 | VAR_flat_graph_node->>'cte_aux_stmt_name', 372 | VAR_flat_graph_node->>'ctab_name', VAR_ctab_pk_cols_list, 373 | VAR_ctab_pk_cols_list, 374 | VAR_ctab_pk_cols_list, VAR_flat_graph_node->>'ctab_name', VAR_ctab_fk_cols_list, VAR_in, 375 | VAR_recursive_term, 376 | VAR_ctab_pk_cols_list 377 | ); 378 | END IF; 379 | END LOOP; 380 | 381 | FOR VAR_flat_graph_node IN SELECT jsonb_array_elements(VAR_flat_graph) LOOP 382 | VAR_selects_for_union := VAR_selects_for_union || format('SELECT %L AS queue_i, count(*) AS n_del FROM %I', 383 | VAR_flat_graph_node->>'i', VAR_flat_graph_node->>'cte_aux_stmt_name' 384 | ); 385 | END LOOP; 386 | 387 | BEGIN 388 | VAR_final_query := format('WITH %s %s', 389 | array_to_string(VAR_cte_aux_stmts, ','), array_to_string(VAR_selects_for_union, ' UNION ') 390 | ); 391 | 392 | -- RAISE INFO '%', VAR_final_query; 393 | 394 | OPEN VAR_del_results_cursor FOR EXECUTE VAR_final_query; 395 | 396 | LOOP 397 | FETCH VAR_del_results_cursor INTO VAR_del_result_rec; 398 | 399 | IF VAR_del_result_rec IS NULL THEN 400 | CLOSE VAR_del_results_cursor; 401 | 402 | EXIT; 403 | END IF; 404 | 405 | VAR_del_results := jsonb_set(VAR_del_results, ARRAY[VAR_del_result_rec.queue_i], VAR_del_result_rec.n_del::TEXT::JSONB); 406 | END LOOP; 407 | 408 | IF NOT ARG_for_realz THEN 409 | RAISE INFO 'DAMAGE PREVIEW (recursively_delete v%)', VAR_version; 410 | RAISE INFO ''; 411 | 412 | FOR VAR_flat_graph_node IN SELECT jsonb_array_elements(VAR_flat_graph) LOOP 413 | RAISE INFO '%', format('%9s %1s %1s %s%s%s', 414 | (CASE WHEN VAR_flat_graph_node->>'delete_action' IN ('d', 'n') THEN '~' ELSE VAR_del_results->>(VAR_flat_graph_node->>'i') END), -- N recs deleted (or to be deleted) 415 | VAR_flat_graph_node->>'delete_action', -- FK constraint type 416 | (CASE WHEN VAR_flat_graph_node->>'i' IN (SELECT jsonb_array_elements(jsonb_array_elements(VAR_circ_deps))->>'i') THEN E'\u221E' ELSE '' END), -- Circular dependency indicator 417 | repeat('| ', coalesce((VAR_flat_graph_node->>'depth')::INTEGER, 0)), -- Indentation 418 | VAR_flat_graph_node->>'ctab_name', -- Relation schema/name 419 | (CASE WHEN (VAR_flat_graph_node->>'depth')::INT = 0 THEN '' ELSE format('.%s', VAR_flat_graph_node->>'ctab_fk_col_names') END) -- Relation FK cols (referencing parent) 420 | ); 421 | END LOOP; 422 | 423 | RAISE INFO ''; 424 | 425 | -- 'ABORT': Five characters. 426 | RAISE EXCEPTION USING errcode = 'ABORT'; 427 | END IF; 428 | EXCEPTION 429 | WHEN SQLSTATE 'ABORT' THEN 430 | NULL; 431 | WHEN OTHERS THEN 432 | RAISE; 433 | END; 434 | 435 | RETURN CASE WHEN ARG_for_realz THEN (VAR_del_results->>'0')::INT ELSE 0 END; 436 | END; 437 | $$; 438 | -------------------------------------------------------------------------------- /sql/uninstall_recursively_delete.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * Author: 3 | * Created at: 2021-04-21 13:46:19 -0700 4 | * 5 | */ 6 | 7 | SET client_min_messages = warning; 8 | 9 | BEGIN; 10 | DROP FUNCTION recursively_delete(regclass, anyelement, boolean); 11 | DROP FUNCTION _recursively_delete (regclass, text[], int, jsonb, int, text[], jsonb, jsonb); 12 | DROP VIEW v_fk_cons; 13 | COMMIT; 14 | -------------------------------------------------------------------------------- /test/expected/install.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION recursively_delete VERSION '0.1.5'; 2 | SELECT extversion 3 | FROM pg_catalog.pg_extension 4 | WHERE extname = 'recursively_delete'; 5 | extversion 6 | ------------ 7 | 0.1.5 8 | (1 row) 9 | 10 | -------------------------------------------------------------------------------- /test/expected/uninstall.out: -------------------------------------------------------------------------------- 1 | DROP EXTENSION recursively_delete; 2 | -------------------------------------------------------------------------------- /test/sql/install.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION recursively_delete VERSION '0.1.5'; 2 | 3 | SELECT extversion 4 | FROM pg_catalog.pg_extension 5 | WHERE extname = 'recursively_delete'; 6 | -------------------------------------------------------------------------------- /test/sql/uninstall.sql: -------------------------------------------------------------------------------- 1 | DROP EXTENSION recursively_delete; 2 | 3 | --------------------------------------------------------------------------------