|
| 1 | +// Adapted from Flyway's Postgre cleaner, Apache2 |
| 2 | +// https://github.com/flyway/flyway/blob/1fc8cff5356f9a151ea72e6d216a5586d4a03b31/flyway-core/src/main/java/org/flywaydb/core/internal/database/postgresql/PostgreSQLSchema.java |
| 3 | + |
| 4 | +import { ClientBase } from "pg"; |
| 5 | + |
| 6 | +let namespace = "public"; |
| 7 | +let currentuser = "postgres"; |
| 8 | + |
| 9 | +export async function doClean(client: ClientBase) { |
| 10 | + for (const statement of await generateDropStatementsForMaterializedViews(client)) { |
| 11 | + await client.query(statement, []); |
| 12 | + } |
| 13 | + |
| 14 | + for (const statement of await generateDropStatementsForViews(client)) { |
| 15 | + await client.query(statement, []); |
| 16 | + } |
| 17 | + |
| 18 | + for (const statement of await generateDropStatementsForTables(client)) { |
| 19 | + await client.query(statement, []); |
| 20 | + } |
| 21 | + |
| 22 | + for (const statement of await generateDropStatementsForBaseTypes(client, true)) { |
| 23 | + await client.query(statement, []); |
| 24 | + } |
| 25 | + |
| 26 | + for (const statement of await generateDropStatementsForRoutines(client)) { |
| 27 | + await client.query(statement, []); |
| 28 | + } |
| 29 | + |
| 30 | + for (const statement of await generateDropStatementsForEnums(client)) { |
| 31 | + await client.query(statement, []); |
| 32 | + } |
| 33 | + |
| 34 | + for (const statement of await generateDropStatementsForDomains(client)) { |
| 35 | + await client.query(statement, []); |
| 36 | + } |
| 37 | + |
| 38 | + for (const statement of await generateDropStatementsForSequences(client)) { |
| 39 | + await client.query(statement, []); |
| 40 | + } |
| 41 | + |
| 42 | + for (const statement of await generateDropStatementsForBaseTypes(client, false)) { |
| 43 | + await client.query(statement, []); |
| 44 | + } |
| 45 | + |
| 46 | + for (const statement of await generateDropStatementsForExtensions(client)) { |
| 47 | + await client.query(statement, []); |
| 48 | + } |
| 49 | +} |
| 50 | + |
| 51 | +async function queryForStringList(client: ClientBase, text: string, ...values: unknown[]): Promise<string[]> { |
| 52 | + return (await client.query({ text, values, rowMode: 'array' })).rows.map(row => row[0]); |
| 53 | +} |
| 54 | + |
| 55 | +/** |
| 56 | + * Generates the statements for dropping the extensions in this schema. |
| 57 | + * |
| 58 | + * @return The drop statements. |
| 59 | + * @throws SQLException when the clean statements could not be generated. |
| 60 | + */ |
| 61 | +async function generateDropStatementsForExtensions(client: ClientBase): Promise<string[]> { |
| 62 | + const statements: string[] = []; |
| 63 | + |
| 64 | + if (await extensionsTableExists(client)) { |
| 65 | + const extensionNames = await queryForStringList(client, |
| 66 | + "SELECT e.extname " + |
| 67 | + "FROM pg_extension e " + |
| 68 | + "LEFT JOIN pg_namespace n ON n.oid = e.extnamespace " + |
| 69 | + "LEFT JOIN pg_roles r ON r.oid = e.extowner " + |
| 70 | + "WHERE n.nspname=$1 AND r.rolname=$2", namespace, currentuser); |
| 71 | + |
| 72 | + for (const extensionName of extensionNames) { |
| 73 | + // XXX: injection |
| 74 | + statements.push("DROP EXTENSION IF EXISTS " + extensionName + " CASCADE"); |
| 75 | + } |
| 76 | + } |
| 77 | + |
| 78 | + return statements; |
| 79 | +} |
| 80 | + |
| 81 | +async function extensionsTableExists(client: ClientBase): Promise<boolean> { |
| 82 | + return !!(await client.query( |
| 83 | + "SELECT EXISTS ( \n" + |
| 84 | + "SELECT 1 \n" + |
| 85 | + "FROM pg_tables \n" + |
| 86 | + "WHERE tablename = 'pg_extension');")).rows[0]; |
| 87 | +} |
| 88 | + |
| 89 | +/** |
| 90 | + * Generates the statements for dropping the sequences in this schema. |
| 91 | + * |
| 92 | + * @return The drop statements. |
| 93 | + * @throws SQLException when the clean statements could not be generated. |
| 94 | + */ |
| 95 | +async function generateDropStatementsForSequences(client: ClientBase): Promise<string[]> { |
| 96 | + const statements: string[] = []; |
| 97 | + const sequenceNames = await queryForStringList(client, "SELECT sequence_name FROM information_schema.sequences WHERE sequence_schema=$1", namespace); |
| 98 | + |
| 99 | + for (const sequenceName of sequenceNames) { |
| 100 | + // XXX: injection |
| 101 | + statements.push("DROP SEQUENCE IF EXISTS " + namespace + "." + sequenceName); |
| 102 | + } |
| 103 | + |
| 104 | + return statements; |
| 105 | +} |
| 106 | + |
| 107 | +/** |
| 108 | + * Generates the statements for dropping the types in this schema. |
| 109 | + * |
| 110 | + * @param recreate Flag indicating whether the types should be recreated. Necessary for type-function chicken and egg problem. |
| 111 | + * @return The drop statements. |
| 112 | + * @throws SQLException when the clean statements could not be generated. |
| 113 | + */ |
| 114 | +async function generateDropStatementsForBaseTypes(client: ClientBase, recreate: boolean): Promise<string[]> { |
| 115 | + const rows: Record<string, string>[] = (await client.query( |
| 116 | + "select typname, typcategory from pg_catalog.pg_type t " |
| 117 | + + "left join pg_depend dep on dep.objid = t.oid and dep.deptype = 'e' " |
| 118 | + + "where (t.typrelid = 0 OR (SELECT c.relkind = 'c' FROM pg_catalog.pg_class c WHERE c.oid = t.typrelid)) " |
| 119 | + + "and NOT EXISTS(SELECT 1 FROM pg_catalog.pg_type el WHERE el.oid = t.typelem AND el.typarray = t.oid) " |
| 120 | + + "and t.typnamespace in (select oid from pg_catalog.pg_namespace where nspname = $1) " |
| 121 | + + "and dep.objid is null " |
| 122 | + + "and t.typtype != 'd'", |
| 123 | + [namespace])).rows; |
| 124 | + |
| 125 | + const statements: string[] = []; |
| 126 | + for (const row of rows) { |
| 127 | + statements.push("DROP TYPE IF EXISTS " + namespace + "." + row.typname + " CASCADE"); |
| 128 | + } |
| 129 | + |
| 130 | + if (recreate) { |
| 131 | + for (const row of rows) { |
| 132 | + // Only recreate Pseudo-types (P) and User-defined types (U) |
| 133 | + if (row.typcategory == "P" || row.typcategory == "U") { |
| 134 | + statements.push("CREATE TYPE " + namespace + "." + row.typname); |
| 135 | + } |
| 136 | + } |
| 137 | + } |
| 138 | + |
| 139 | + return statements; |
| 140 | +} |
| 141 | + |
| 142 | +/** |
| 143 | + * Generates the statements for dropping the routines in this schema. |
| 144 | + * |
| 145 | + * @return The drop statements. |
| 146 | + * @throws SQLException when the clean statements could not be generated. |
| 147 | + */ |
| 148 | +async function generateDropStatementsForRoutines(client: ClientBase): Promise<string[]> { |
| 149 | + const rows: any[] = (await client.query( |
| 150 | + // Search for all functions |
| 151 | + "SELECT proname, oidvectortypes(proargtypes) AS args, pg_proc.prokind AS prokind " |
| 152 | + + "FROM pg_proc INNER JOIN pg_namespace ns ON (pg_proc.pronamespace = ns.oid) " |
| 153 | + // that don't depend on an extension |
| 154 | + + "LEFT JOIN pg_depend dep ON dep.objid = pg_proc.oid AND dep.deptype = 'e' " |
| 155 | + + "WHERE ns.nspname = $1 AND dep.objid IS NULL", |
| 156 | + [namespace] |
| 157 | + )).rows; |
| 158 | + |
| 159 | + const statements: string[] = []; |
| 160 | + for (const row of rows) { |
| 161 | + let type = "FUNCTION"; |
| 162 | + if (row.prokind == 'a') { |
| 163 | + type = "AGGREGATE"; |
| 164 | + } else if (row.prokind == 'p') { |
| 165 | + type = "PROCEDURE"; |
| 166 | + } |
| 167 | + statements.push("DROP " + type + " IF EXISTS " + namespace + "." + row.proname + "(" + row.args + ") CASCADE"); |
| 168 | + } |
| 169 | + return statements; |
| 170 | +} |
| 171 | + |
| 172 | +/** |
| 173 | + * Generates the statements for dropping the enums in this schema. |
| 174 | + * |
| 175 | + * @return The drop statements. |
| 176 | + * @throws SQLException when the clean statements could not be generated. |
| 177 | + */ |
| 178 | +async function generateDropStatementsForEnums(client: ClientBase): Promise<string[]> { |
| 179 | + const enumNames = await queryForStringList(client, "SELECT t.typname FROM pg_catalog.pg_type t INNER JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace WHERE n.nspname = $1 and t.typtype = 'e'", namespace); |
| 180 | + |
| 181 | + const statements: string[] = []; |
| 182 | + for (const enumName of enumNames) { |
| 183 | + statements.push("DROP TYPE " + namespace + "." + enumName); |
| 184 | + } |
| 185 | + |
| 186 | + return statements; |
| 187 | +} |
| 188 | + |
| 189 | +/** |
| 190 | + * Generates the statements for dropping the domains in this schema. |
| 191 | + * |
| 192 | + * @return The drop statements. |
| 193 | + * @throws SQLException when the clean statements could not be generated. |
| 194 | + */ |
| 195 | +async function generateDropStatementsForDomains(client: ClientBase): Promise<string[]> { |
| 196 | + const domainNames = await queryForStringList(client, |
| 197 | + "SELECT t.typname as domain_name\n" + |
| 198 | + "FROM pg_catalog.pg_type t\n" + |
| 199 | + " LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace\n" + |
| 200 | + " LEFT JOIN pg_depend dep ON dep.objid = t.oid AND dep.deptype = 'e'\n" + |
| 201 | + "WHERE t.typtype = 'd'\n" + |
| 202 | + " AND n.nspname = $1\n" + |
| 203 | + " AND dep.objid IS NULL" |
| 204 | + , namespace); |
| 205 | + |
| 206 | + const statements: string[] = []; |
| 207 | + for (const domainName of domainNames) { |
| 208 | + statements.push("DROP DOMAIN " + namespace + "." + domainName); |
| 209 | + } |
| 210 | + |
| 211 | + return statements; |
| 212 | +} |
| 213 | + |
| 214 | +/** |
| 215 | + * Generates the statements for dropping the materialized views in this schema. |
| 216 | + * |
| 217 | + * @return The drop statements. |
| 218 | + * @throws SQLException when the clean statements could not be generated. |
| 219 | + */ |
| 220 | +async function generateDropStatementsForMaterializedViews(client: ClientBase): Promise<string[]> { |
| 221 | + const viewNames = await queryForStringList(client, |
| 222 | + "SELECT relname FROM pg_catalog.pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace" |
| 223 | + + " WHERE c.relkind = 'm' AND n.nspname = $1", namespace); |
| 224 | + |
| 225 | + const statements: string[] = []; |
| 226 | + for (const domainName of viewNames) { |
| 227 | + statements.push("DROP MATERIALIZED VIEW IF EXISTS " + namespace + "." + domainName + " CASCADE"); |
| 228 | + } |
| 229 | + |
| 230 | + return statements; |
| 231 | +} |
| 232 | + |
| 233 | +/** |
| 234 | + * Generates the statements for dropping the views in this schema. |
| 235 | + * |
| 236 | + * @return The drop statements. |
| 237 | + * @throws SQLException when the clean statements could not be generated. |
| 238 | + */ |
| 239 | +async function generateDropStatementsForViews(client: ClientBase): Promise<string[]> { |
| 240 | + const viewNames = await queryForStringList(client, |
| 241 | + // Search for all views |
| 242 | + "SELECT relname FROM pg_catalog.pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace" + |
| 243 | + // that don't depend on an extension |
| 244 | + " LEFT JOIN pg_depend dep ON dep.objid = c.oid AND dep.deptype = 'e'" + |
| 245 | + " WHERE c.relkind = 'v' AND n.nspname = $1 AND dep.objid IS NULL", |
| 246 | + namespace); |
| 247 | + const statements: string[] = []; |
| 248 | + for (const domainName of viewNames) { |
| 249 | + statements.push("DROP VIEW IF EXISTS " + namespace + "." + domainName + " CASCADE"); |
| 250 | + } |
| 251 | + |
| 252 | + return statements; |
| 253 | +} |
| 254 | + |
| 255 | +async function generateDropStatementsForTables(client: ClientBase): Promise<string[]> { |
| 256 | + const tableNames = await queryForStringList(client, |
| 257 | + //Search for all the table names |
| 258 | + "SELECT t.table_name FROM information_schema.tables t" + |
| 259 | + // that don't depend on an extension |
| 260 | + " LEFT JOIN pg_depend dep ON dep.objid = (quote_ident(t.table_schema)||'.'||quote_ident(t.table_name))::regclass::oid AND dep.deptype = 'e'" + |
| 261 | + // in this schema |
| 262 | + " WHERE table_schema=$1" + |
| 263 | + //that are real tables (as opposed to views) |
| 264 | + " AND table_type='BASE TABLE'" + |
| 265 | + // with no extension depending on them |
| 266 | + " AND dep.objid IS NULL" + |
| 267 | + // and are not child tables (= do not inherit from another table). |
| 268 | + " AND NOT (SELECT EXISTS (SELECT inhrelid FROM pg_catalog.pg_inherits" + |
| 269 | + " WHERE inhrelid = (quote_ident(t.table_schema)||'.'||quote_ident(t.table_name))::regclass::oid))", |
| 270 | + namespace |
| 271 | + ); |
| 272 | + //Views and child tables are excluded as they are dropped with the parent table when using cascade. |
| 273 | + |
| 274 | + const tables = []; |
| 275 | + for (const tableName of tableNames) { |
| 276 | + tables.push("DROP TABLE IF EXISTS " + tableName + " CASCADE"); |
| 277 | + } |
| 278 | + return tables; |
| 279 | +} |
0 commit comments