File: pg_repack.sql.in

package info (click to toggle)
pg-repack 1.5.3-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 832 kB
  • sloc: ansic: 5,016; sql: 471; makefile: 107; sh: 12
file content (382 lines) | stat: -rw-r--r-- 13,222 bytes parent folder | download | duplicates (2)
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
/*
 * pg_repack: lib/pg_repack.sql.in
 *
 * Portions Copyright (c) 2008-2011, NIPPON TELEGRAPH AND TELEPHONE CORPORATION
 * Portions Copyright (c) 2011, Itagaki Takahiro
 * Portions Copyright (c) 2012-2020, The Reorg Development Team
 */

CREATE SCHEMA repack;

CREATE FUNCTION repack.version() RETURNS text AS
'MODULE_PATHNAME', 'repack_version'
LANGUAGE C IMMUTABLE STRICT;

CREATE FUNCTION repack.version_sql() RETURNS text AS
$$SELECT 'pg_repack REPACK_VERSION'::text$$
LANGUAGE SQL IMMUTABLE STRICT;

-- Always specify search_path to 'pg_catalog' so that we
-- always can get schema-qualified relation name
CREATE FUNCTION repack.oid2text(oid) RETURNS text AS
$$
	SELECT textin(regclassout($1));
$$
LANGUAGE sql STABLE STRICT SET search_path to 'pg_catalog';

-- Get a comma-separated column list of the index.
--
-- Columns are quoted as literals because they are going to be passed to
-- the `repack_trigger` function as text arguments. `repack_trigger` will quote
-- them as identifiers later.
CREATE FUNCTION repack.get_index_columns(oid) RETURNS text AS
$$
  SELECT coalesce(string_agg(quote_literal(attname), ', '), '')
    FROM pg_attribute,
         (SELECT indrelid,
                 indkey,
                 generate_series(0, indnatts-1) AS i
            FROM pg_index
           WHERE indexrelid = $1
         ) AS keys
   WHERE attrelid = indrelid
     AND attnum = indkey[i];
$$
LANGUAGE sql STABLE STRICT;

CREATE FUNCTION repack.get_order_by(oid, oid) RETURNS text AS
'MODULE_PATHNAME', 'repack_get_order_by'
LANGUAGE C STABLE STRICT;

CREATE FUNCTION repack.create_log_table(oid) RETURNS void AS
$$
BEGIN
    EXECUTE 'CREATE TABLE repack.log_' || $1 ||
            ' (id bigserial PRIMARY KEY,' ||
            ' pk repack.pk_' || $1 || ',' ||
            ' row ' || repack.oid2text($1) || ')';
END
$$
LANGUAGE plpgsql;

CREATE FUNCTION repack.create_table(oid, name) RETURNS void AS
$$
BEGIN
    EXECUTE 'CREATE TABLE repack.table_' || $1 ||
            ' WITH (' || repack.get_storage_param($1) || ') ' ||
            ' TABLESPACE ' || quote_ident($2) ||
            ' AS SELECT ' || repack.get_columns_for_create_as($1) ||
            ' FROM ONLY ' || repack.oid2text($1) || ' WITH NO DATA';
END
$$
LANGUAGE plpgsql;

CREATE FUNCTION repack.create_index_type(oid, oid) RETURNS void AS
$$
BEGIN
    EXECUTE repack.get_create_index_type($1, 'repack.pk_' || $2);
END
$$
LANGUAGE plpgsql;

CREATE FUNCTION repack.get_create_index_type(oid, name) RETURNS text AS
$$
  SELECT 'CREATE TYPE ' || $2 || ' AS (' ||
         coalesce(string_agg(quote_ident(attname) || ' ' ||
           pg_catalog.format_type(atttypid, atttypmod), ', '), '') || ')'
    FROM pg_attribute,
         (SELECT indrelid,
                 indkey,
                 generate_series(0, indnatts-1) AS i
            FROM pg_index
           WHERE indexrelid = $1
         ) AS keys
   WHERE attrelid = indrelid
     AND attnum = indkey[i];
$$
LANGUAGE sql STABLE STRICT;

CREATE FUNCTION repack.get_create_trigger(relid oid, pkid oid)
  RETURNS text AS
$$
  SELECT 'CREATE TRIGGER repack_trigger' ||
         ' AFTER INSERT OR DELETE OR UPDATE ON ' || repack.oid2text($1) ||
         ' FOR EACH ROW EXECUTE PROCEDURE repack.repack_trigger(' ||
         repack.get_index_columns($2) || ')';
$$
LANGUAGE sql STABLE STRICT;

CREATE FUNCTION repack.get_enable_trigger(relid oid)
  RETURNS text AS
$$
  SELECT 'ALTER TABLE ' || repack.oid2text($1) ||
    ' ENABLE ALWAYS TRIGGER repack_trigger';
$$
LANGUAGE sql STABLE STRICT;

CREATE FUNCTION repack.get_assign(oid, text) RETURNS text AS
$$
  SELECT '(' || coalesce(string_agg(quote_ident(attname), ', '), '') ||
         ') = (' || $2 || '.' ||
         coalesce(string_agg(quote_ident(attname), ', ' || $2 || '.'), '') || ')'
    FROM (SELECT attname FROM pg_attribute
           WHERE attrelid = $1 AND attnum > 0 AND NOT attisdropped
           ORDER BY attnum) tmp;
$$
LANGUAGE sql STABLE STRICT;

CREATE FUNCTION repack.get_compare_pkey(oid, text)
  RETURNS text AS
$$
  SELECT '(' || coalesce(string_agg(quote_ident(attname), ', '), '') ||
         ') = (' || $2 || '.' ||
         coalesce(string_agg(quote_ident(attname), ', ' || $2 || '.'), '') || ')'
    FROM pg_attribute,
         (SELECT indrelid,
                 indkey,
                 generate_series(0, indnatts-1) AS i
            FROM pg_index
           WHERE indexrelid = $1
         ) AS keys
   WHERE attrelid = indrelid
     AND attnum = indkey[i];
$$
LANGUAGE sql STABLE STRICT;

-- Get a column list for SELECT all columns including dropped ones.
-- We use NULLs of integer types for dropped columns (types are not important).
CREATE FUNCTION repack.get_columns_for_create_as(oid)
  RETURNS text AS
$$
SELECT coalesce(string_agg(c, ','), '') FROM (SELECT
	CASE WHEN attisdropped
		THEN 'NULL::integer AS ' || quote_ident(attname)
		ELSE quote_ident(attname)
	END AS c
FROM pg_attribute
WHERE attrelid = $1 AND attnum > 0 ORDER BY attnum
) AS COL
$$
LANGUAGE sql STABLE STRICT;

-- Get a SQL text to DROP dropped columns for the table,
-- or NULL if it has no dropped columns.
CREATE FUNCTION repack.get_drop_columns(oid, text)
  RETURNS text AS
$$
SELECT
	'ALTER TABLE ' || $2 || ' ' || array_to_string(dropped_columns, ', ')
FROM (
	SELECT
		array_agg('DROP COLUMN ' || quote_ident(attname)) AS dropped_columns
	FROM (
		SELECT * FROM pg_attribute
		WHERE attrelid = $1 AND attnum > 0 AND attisdropped
		ORDER BY attnum
	) T
) T
WHERE
	array_upper(dropped_columns, 1) > 0
$$
LANGUAGE sql STABLE STRICT;

-- Get a comma-separated storage parameter for the table including
-- parameters for the corresponding TOAST table.
-- Note that since oid setting is always not NULL, this function
-- never returns NULL
CREATE FUNCTION repack.get_storage_param(oid)
  RETURNS TEXT AS
$$
SELECT string_agg(param, ', ')
FROM (
    -- table storage parameter
    SELECT unnest(reloptions) as param
    FROM pg_class
    WHERE oid = $1
    UNION ALL
    -- TOAST table storage parameter
    SELECT ('toast.' || unnest(reloptions)) as param
    FROM (
        SELECT reltoastrelid from pg_class where oid = $1
         ) as t,
        pg_class as c
    WHERE c.oid = t.reltoastrelid
    UNION ALL
    -- table oid
    SELECT 'oids = ' ||
        CASE WHEN relhasoids
            THEN 'true'
            ELSE 'false'
        END
    FROM pg_class
    WHERE oid = $1

    ) as t
$$
LANGUAGE sql STABLE STRICT;

-- GET a SQL text to set column storage option for the table.
CREATE FUNCTION repack.get_alter_col_storage(oid)
  RETURNS text AS
$$
 SELECT 'ALTER TABLE repack.table_' || $1 || array_to_string(column_storage, ',')
 FROM (
       SELECT
         array_agg(' ALTER ' || quote_ident(attname) ||
          CASE attstorage
               WHEN 'p' THEN ' SET STORAGE PLAIN'
               WHEN 'm' THEN ' SET STORAGE MAIN'
               WHEN 'e' THEN ' SET STORAGE EXTERNAL'
               WHEN 'x' THEN ' SET STORAGE EXTENDED'
          END) AS column_storage
       FROM (
            SELECT *
            FROM pg_attribute a
                 JOIN pg_type t on t.oid = atttypid
                 JOIN pg_class r on r.oid = a.attrelid
                 JOIN pg_namespace s on s.oid = r.relnamespace
            WHERE typstorage <> attstorage
                 AND attrelid = $1
                 AND attnum > 0
                 AND NOT attisdropped
           ORDER BY attnum
	   ) T
      ) T
WHERE array_upper(column_storage , 1) > 0
$$
LANGUAGE sql STABLE STRICT;

-- includes not only PRIMARY KEYS but also UNIQUE NOT NULL keys
DO $$
BEGIN
    IF current_setting('server_version_num')::int >= 110000 THEN
        CREATE VIEW repack.primary_keys AS
          SELECT indrelid, min(indexrelid) AS indexrelid
            FROM (SELECT indrelid, indexrelid FROM pg_index
           WHERE indisunique
             AND indisvalid
             AND indpred IS NULL
             AND 0 <> ALL(indkey)
             AND NOT EXISTS(
                   SELECT 1 FROM pg_attribute
                    WHERE attrelid = indrelid
                      -- indkey is 0-based int2vector
                      AND attnum = ANY(indkey[0:indnkeyatts - 1])
                      AND NOT attnotnull)
           ORDER BY indrelid, indisprimary DESC, indnatts, indkey) tmp
           GROUP BY indrelid;
    ELSE
        CREATE VIEW repack.primary_keys AS
          SELECT indrelid, min(indexrelid) AS indexrelid
            FROM (SELECT indrelid, indexrelid FROM pg_index
           WHERE indisunique
             AND indisvalid
             AND indpred IS NULL
             AND 0 <> ALL(indkey)
             AND NOT EXISTS(
                   SELECT 1 FROM pg_attribute
                    WHERE attrelid = indrelid
                      AND attnum = ANY(indkey)
                      AND NOT attnotnull)
           ORDER BY indrelid, indisprimary DESC, indnatts, indkey) tmp
           GROUP BY indrelid;
    END IF;
END;
$$;

CREATE VIEW repack.tables AS
  SELECT repack.oid2text(R.oid) AS relname,
         R.oid AS relid,
         R.reltoastrelid AS reltoastrelid,
         CASE WHEN R.reltoastrelid = 0 THEN 0 ELSE (
            SELECT indexrelid FROM pg_index
            WHERE indrelid = R.reltoastrelid
            AND indisvalid) END AS reltoastidxid,
         N.nspname AS schemaname,
         PK.indexrelid AS pkid,
         CK.indexrelid AS ckid,
         'SELECT repack.create_index_type(' || PK.indexrelid || ',' || R.oid || ')' AS create_pktype,
         'SELECT repack.create_log_table(' || R.oid || ')' AS create_log,
         repack.get_create_trigger(R.oid, PK.indexrelid) AS create_trigger,
         repack.get_enable_trigger(R.oid) as enable_trigger,
         'SELECT repack.create_table($1, $2)'::text AS create_table,
         coalesce(S.spcname, S2.spcname) AS tablespace_orig,
         'INSERT INTO repack.table_' || R.oid || ' SELECT ' || repack.get_columns_for_create_as(R.oid) || ' FROM ONLY ' || repack.oid2text(R.oid) AS copy_data,
         repack.get_alter_col_storage(R.oid) AS alter_col_storage,
         repack.get_drop_columns(R.oid, 'repack.table_' || R.oid) AS drop_columns,
         'DELETE FROM repack.log_' || R.oid AS delete_log,
         'LOCK TABLE ' || repack.oid2text(R.oid) || ' IN ACCESS EXCLUSIVE MODE' AS lock_table,
         repack.get_order_by(CK.indexrelid, R.oid) AS ckey,
         'SELECT * FROM repack.log_' || R.oid || ' ORDER BY id LIMIT $1' AS sql_peek,
         'INSERT INTO repack.table_' || R.oid || ' VALUES ($1.*)' AS sql_insert,
         'DELETE FROM repack.table_' || R.oid || ' WHERE ' || repack.get_compare_pkey(PK.indexrelid, '$1') AS sql_delete,
         'UPDATE repack.table_' || R.oid || ' SET ' || repack.get_assign(R.oid, '$2') || ' WHERE ' || repack.get_compare_pkey(PK.indexrelid, '$1') AS sql_update,
         'DELETE FROM repack.log_' || R.oid || ' WHERE id IN (' AS sql_pop
    FROM pg_class R
         LEFT JOIN pg_class T ON R.reltoastrelid = T.oid
         LEFT JOIN repack.primary_keys PK
                ON R.oid = PK.indrelid
         LEFT JOIN (SELECT CKI.* FROM pg_index CKI, pg_class CKT
                     WHERE CKI.indisvalid
                       AND CKI.indexrelid = CKT.oid
                       AND CKI.indisclustered
                       AND CKT.relam = 403) CK
                ON R.oid = CK.indrelid
         LEFT JOIN pg_namespace N ON N.oid = R.relnamespace
         LEFT JOIN pg_tablespace S ON S.oid = R.reltablespace
         CROSS JOIN (SELECT S2.spcname
             FROM pg_catalog.pg_database D
             JOIN pg_catalog.pg_tablespace S2 ON S2.oid = D.dattablespace
             WHERE D.datname = current_database()) S2
   WHERE R.relkind = 'r'
     AND R.relpersistence = 'p'
     AND N.nspname NOT IN ('pg_catalog', 'information_schema')
     AND N.nspname NOT LIKE E'pg\\_temp\\_%';

CREATE FUNCTION repack.repack_indexdef(oid, oid, name, bool) RETURNS text AS
'MODULE_PATHNAME', 'repack_indexdef'
LANGUAGE C STABLE;

CREATE FUNCTION repack.repack_trigger() RETURNS trigger AS
'MODULE_PATHNAME', 'repack_trigger'
LANGUAGE C VOLATILE STRICT SECURITY DEFINER
SET search_path = pg_catalog, pg_temp;

CREATE FUNCTION repack.conflicted_triggers(oid) RETURNS SETOF name AS
$$
SELECT tgname FROM pg_trigger
 WHERE tgrelid = $1 AND tgname = 'repack_trigger'
 ORDER BY tgname;
$$
LANGUAGE sql STABLE STRICT;

CREATE FUNCTION repack.disable_autovacuum(regclass) RETURNS void AS
'MODULE_PATHNAME', 'repack_disable_autovacuum'
LANGUAGE C VOLATILE STRICT;

CREATE FUNCTION repack.repack_apply(
  sql_peek      cstring,
  sql_insert    cstring,
  sql_delete    cstring,
  sql_update    cstring,
  sql_pop       cstring,
  count         integer)
RETURNS integer AS
'MODULE_PATHNAME', 'repack_apply'
LANGUAGE C VOLATILE;

CREATE FUNCTION repack.repack_swap(oid) RETURNS void AS
'MODULE_PATHNAME', 'repack_swap'
LANGUAGE C VOLATILE STRICT;

CREATE FUNCTION repack.repack_drop(oid, int) RETURNS void AS
'MODULE_PATHNAME', 'repack_drop'
LANGUAGE C VOLATILE STRICT;

CREATE FUNCTION repack.repack_index_swap(oid) RETURNS void AS
'MODULE_PATHNAME', 'repack_index_swap'
LANGUAGE C STABLE STRICT;

CREATE FUNCTION repack.get_table_and_inheritors(regclass) RETURNS regclass[] AS
'MODULE_PATHNAME', 'repack_get_table_and_inheritors'
LANGUAGE C STABLE STRICT;