Project

General

Profile

1 2094 aaronmk
--
2
-- PostgreSQL database dump
3
--
4
5
SET statement_timeout = 0;
6 11667 aaronmk
SET lock_timeout = 0;
7 2094 aaronmk
SET client_encoding = 'UTF8';
8 6213 aaronmk
SET standard_conforming_strings = on;
9 2094 aaronmk
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11
12
--
13 8183 aaronmk
-- Name: util; Type: SCHEMA; Schema: -; Owner: -
14 2094 aaronmk
--
15
16 8183 aaronmk
CREATE SCHEMA util;
17 2094 aaronmk
18
19 4982 aaronmk
--
20 8183 aaronmk
-- Name: SCHEMA util; Type: COMMENT; Schema: -; Owner: -
21 4982 aaronmk
--
22
23 12235 aaronmk
COMMENT ON SCHEMA util IS '
24
IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.
25 4982 aaronmk
26 12235 aaronmk
NOTE: IMMUTABLE SQL-language functions should never be declared STRICT, because this prevents them from being inlined. inlining can create a significant speed improvement (7x+), by avoiding function calls and enabling additional constant folding.
27
';
28 4982 aaronmk
29 10378 aaronmk
30 8183 aaronmk
SET search_path = util, pg_catalog;
31 2107 aaronmk
32 2094 aaronmk
--
33 8183 aaronmk
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
34 8107 aaronmk
--
35
36
CREATE TYPE col_cast AS (
37
	col_name text,
38
	type regtype
39
);
40
41
42
--
43 8183 aaronmk
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
44 8106 aaronmk
--
45
46
CREATE TYPE col_ref AS (
47
	table_ regclass,
48
	name text
49
);
50
51
52
--
53 8183 aaronmk
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
54 7673 aaronmk
--
55
56
CREATE TYPE compass_dir AS ENUM (
57
    'N',
58
    'E',
59
    'S',
60
    'W'
61
);
62
63
64
--
65 8183 aaronmk
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
66 2610 aaronmk
--
67
68
CREATE TYPE datatype AS ENUM (
69
    'str',
70
    'float'
71
);
72
73
74
--
75 8183 aaronmk
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76 2596 aaronmk
--
77
78 4501 aaronmk
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
79 3422 aaronmk
    LANGUAGE sql IMMUTABLE
80
    AS $_$
81 4501 aaronmk
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
82 3422 aaronmk
$_$;
83
84
85
--
86 8183 aaronmk
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
87 5937 aaronmk
--
88
89 5956 aaronmk
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
90 5937 aaronmk
    LANGUAGE sql IMMUTABLE
91
    AS $_$
92
SELECT bool_and(value)
93
FROM
94
(VALUES
95
      ($1)
96
    , ($2)
97 5956 aaronmk
    , ($3)
98
    , ($4)
99
    , ($5)
100 5937 aaronmk
)
101
AS v (value)
102
$_$;
103
104
105
--
106 8183 aaronmk
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
107 5937 aaronmk
--
108
109 12235 aaronmk
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
110
_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.
111
';
112 5937 aaronmk
113
114
--
115 8183 aaronmk
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
116 7704 aaronmk
--
117
118
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
119
    LANGUAGE sql IMMUTABLE
120
    AS $_$
121
SELECT avg(value)
122
FROM
123
(VALUES
124
      ($1)
125
    , ($2)
126
    , ($3)
127
    , ($4)
128
    , ($5)
129
)
130
AS v (value)
131
$_$;
132
133
134
--
135 8183 aaronmk
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
136 7679 aaronmk
--
137
138
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
139
    LANGUAGE sql IMMUTABLE STRICT
140
    AS $_$
141 8183 aaronmk
SELECT (g[1]||'1')::integer*util._dms_to_dd(deg := g[2]::double precision, min := g[3]::double precision, sec := g[4]::double precision, dir := g[5]::util.compass_dir)
142 7698 aaronmk
FROM
143
(
144
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
145
    UNION ALL
146 7702 aaronmk
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
147
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
148 7698 aaronmk
)
149
matches (g)
150 7679 aaronmk
$_$;
151
152
153
--
154 8183 aaronmk
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
155 7672 aaronmk
--
156
157 7674 aaronmk
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
158 7672 aaronmk
    LANGUAGE sql IMMUTABLE
159
    AS $_$
160 8183 aaronmk
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
161 7672 aaronmk
FROM
162
(VALUES
163 7677 aaronmk
      ($1)
164 7672 aaronmk
    , ($2/60)
165
    , ($3/60/60)
166
)
167
AS v (value)
168
$_$;
169
170
171
--
172 8183 aaronmk
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
173 7723 aaronmk
--
174
175
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
176
    LANGUAGE sql IMMUTABLE
177
    AS $_$
178 8183 aaronmk
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
179 7723 aaronmk
$_$;
180
181
182
--
183 8183 aaronmk
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
184 4142 aaronmk
--
185
186
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
187
    LANGUAGE sql IMMUTABLE
188
    AS $_$
189
SELECT $1 = $2
190
$_$;
191
192
193
--
194 8183 aaronmk
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
195 7396 aaronmk
--
196
197
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
198
    LANGUAGE sql IMMUTABLE
199
    AS $_$
200
-- Fix dates after threshold date
201
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
202
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
203
$_$;
204
205
206
--
207 8183 aaronmk
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
208 4147 aaronmk
--
209
210
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
211
    LANGUAGE sql IMMUTABLE
212
    AS $_$
213
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
214
$_$;
215
216
217
--
218 8183 aaronmk
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
219 4147 aaronmk
--
220
221
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
222
    LANGUAGE sql IMMUTABLE
223
    AS $_$
224 8183 aaronmk
SELECT util._if($1 != '', $2, $3)
225 4147 aaronmk
$_$;
226
227
228
--
229 10699 aaronmk
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
230 4325 aaronmk
--
231
232 10699 aaronmk
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
233 4325 aaronmk
    LANGUAGE sql IMMUTABLE
234
    AS $_$
235 7848 aaronmk
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
236 4325 aaronmk
$_$;
237
238
239
--
240 10699 aaronmk
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
241 5009 aaronmk
--
242
243 10699 aaronmk
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
244 5009 aaronmk
    LANGUAGE sql IMMUTABLE
245
    AS $_$
246 7848 aaronmk
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
247 5009 aaronmk
$_$;
248
249
250
--
251 10699 aaronmk
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
252 3422 aaronmk
--
253
254 10699 aaronmk
CREATE FUNCTION _label(label text, value text) RETURNS text
255 4682 aaronmk
    LANGUAGE sql IMMUTABLE
256
    AS $_$
257
SELECT coalesce($1 || ': ', '') || $2
258
$_$;
259 2596 aaronmk
260
261
--
262 8825 aaronmk
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
263
--
264
265
CREATE FUNCTION _lowercase(value text) RETURNS text
266 10388 aaronmk
    LANGUAGE sql IMMUTABLE
267 8825 aaronmk
    AS $_$
268
SELECT lower($1)
269
$_$;
270
271
272
--
273 11667 aaronmk
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
274
--
275
276
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
277
    LANGUAGE plpgsql IMMUTABLE STRICT
278
    AS $$
279
DECLARE
280
    result value%TYPE := util._map(map, value::text)::unknown;
281
BEGIN
282
    RETURN result;
283
END;
284
$$;
285
286
287
--
288 8183 aaronmk
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
289 6222 aaronmk
--
290
291
CREATE FUNCTION _map(map hstore, value text) RETURNS text
292 7820 aaronmk
    LANGUAGE plpgsql IMMUTABLE STRICT
293 6222 aaronmk
    AS $$
294
DECLARE
295 6271 aaronmk
    match text := map -> value;
296 6222 aaronmk
BEGIN
297 6271 aaronmk
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
298
        match := map -> '*'; -- use default entry
299
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
300
        END IF;
301
    END IF;
302
303
    -- Interpret result
304 6243 aaronmk
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
305
    ELSIF match = '*' THEN RETURN value;
306
    ELSE RETURN match;
307 6222 aaronmk
    END IF;
308
END;
309
$$;
310
311
312
--
313 8183 aaronmk
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
314 5408 aaronmk
--
315
316
CREATE FUNCTION _max("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
317
    LANGUAGE sql IMMUTABLE
318
    AS $_$
319 7289 aaronmk
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
320 5408 aaronmk
$_$;
321
322
323
--
324 8183 aaronmk
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
325 2940 aaronmk
--
326
327 4150 aaronmk
CREATE FUNCTION _merge("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
328 2940 aaronmk
    LANGUAGE sql IMMUTABLE
329
    AS $_$
330 8183 aaronmk
SELECT util.join_strs(value, '; ')
331 2940 aaronmk
FROM
332
(
333
    SELECT *
334
    FROM
335
    (
336
        SELECT
337
        DISTINCT ON (value)
338
        *
339
        FROM
340
        (VALUES
341 4012 aaronmk
              (1, $1)
342
            , (2, $2)
343
            , (3, $3)
344
            , (4, $4)
345
            , (5, $5)
346
            , (6, $6)
347
            , (7, $7)
348
            , (8, $8)
349
            , (9, $9)
350
            , (10, $10)
351 2940 aaronmk
        )
352
        AS v (sort_order, value)
353 4011 aaronmk
        WHERE value IS NOT NULL
354 2940 aaronmk
    )
355
    AS v
356
    ORDER BY sort_order
357
)
358
AS v
359
$_$;
360
361
362
--
363 8183 aaronmk
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
364 7140 aaronmk
--
365
366
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
367
    LANGUAGE sql IMMUTABLE
368
    AS $_$
369
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
370
$_$;
371
372
373
--
374 8183 aaronmk
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
375 6354 aaronmk
--
376
377
CREATE FUNCTION _merge_words("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
378
    LANGUAGE sql IMMUTABLE
379
    AS $_$
380 8183 aaronmk
SELECT util.join_strs(value, ' ')
381 6354 aaronmk
FROM
382
(
383
    SELECT *
384
    FROM
385
    (
386
        SELECT
387
        DISTINCT ON (value)
388
        *
389
        FROM
390
        (VALUES
391
              (1, $1)
392
            , (2, $2)
393
            , (3, $3)
394
            , (4, $4)
395
            , (5, $5)
396
            , (6, $6)
397
            , (7, $7)
398
            , (8, $8)
399
            , (9, $9)
400
            , (10, $10)
401
        )
402
        AS v (sort_order, value)
403
        WHERE value IS NOT NULL
404
    )
405
    AS v
406
    ORDER BY sort_order
407
)
408
AS v
409
$_$;
410
411
412
--
413 8183 aaronmk
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
414 5408 aaronmk
--
415
416
CREATE FUNCTION _min("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
417
    LANGUAGE sql IMMUTABLE
418
    AS $_$
419 7289 aaronmk
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
420 5408 aaronmk
$_$;
421
422
423
--
424 8183 aaronmk
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
425 6316 aaronmk
--
426
427
CREATE FUNCTION _not(value boolean) RETURNS boolean
428 10388 aaronmk
    LANGUAGE sql IMMUTABLE
429 6316 aaronmk
    AS $_$
430
SELECT NOT $1
431
$_$;
432
433
434
--
435 8183 aaronmk
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
436 7104 aaronmk
--
437
438
CREATE FUNCTION _now() RETURNS timestamp with time zone
439
    LANGUAGE sql STABLE
440
    AS $$
441
SELECT now()
442
$$;
443
444
445
--
446 11667 aaronmk
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
447
--
448
449
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
450
    LANGUAGE sql IMMUTABLE
451
    AS $_$
452
SELECT util."_nullIf"($1, $2, $3::util.datatype)
453
$_$;
454
455
456
--
457 8183 aaronmk
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
458 2949 aaronmk
--
459
460 4475 aaronmk
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
461 2949 aaronmk
    LANGUAGE plpgsql IMMUTABLE
462
    AS $$
463
DECLARE
464 8183 aaronmk
    type util.datatype NOT NULL := type; -- add NOT NULL
465 2949 aaronmk
BEGIN
466 4475 aaronmk
    IF type = 'str' THEN RETURN nullif(value::text, "null");
467 2722 aaronmk
    -- Invalid value is ignored, but invalid null value generates error
468 2949 aaronmk
    ELSIF type = 'float' THEN
469 2722 aaronmk
        DECLARE
470
            -- Outside the try block so that invalid null value generates error
471 2949 aaronmk
            "null" double precision := "null"::double precision;
472 2722 aaronmk
        BEGIN
473 2949 aaronmk
            RETURN nullif(value::double precision, "null");
474 2722 aaronmk
        EXCEPTION
475 2949 aaronmk
            WHEN data_exception THEN RETURN value; -- ignore invalid value
476 2722 aaronmk
        END;
477 2610 aaronmk
    END IF;
478
END;
479
$$;
480
481
482
--
483 8183 aaronmk
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
484 6355 aaronmk
--
485
486
CREATE FUNCTION _or("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
487
    LANGUAGE sql IMMUTABLE
488
    AS $_$
489
SELECT bool_or(value)
490
FROM
491
(VALUES
492
      ($1)
493
    , ($2)
494
    , ($3)
495
    , ($4)
496
    , ($5)
497
)
498
AS v (value)
499
$_$;
500
501
502
--
503 8183 aaronmk
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
504 6437 aaronmk
--
505
506 12235 aaronmk
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
507
_or() ignores NULL values, while OR combines them with the other values to potentially convert false to NULL. OR should be used with required fields, and _or() with optional fields.
508
';
509 6437 aaronmk
510
511
--
512 8183 aaronmk
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
513 7706 aaronmk
--
514
515
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
516
    LANGUAGE sql IMMUTABLE
517
    AS $_$
518
SELECT $2 - $1
519
$_$;
520
521
522
--
523 8183 aaronmk
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
524 6793 aaronmk
--
525
526
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
527 10388 aaronmk
    LANGUAGE sql IMMUTABLE
528 6793 aaronmk
    AS $_$
529
SELECT regexp_split_to_table($1, $2)
530
$_$;
531
532
533
--
534 10594 aaronmk
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
535
--
536
537
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
538
    LANGUAGE sql STABLE STRICT
539
    AS $_$
540
SELECT util.derived_cols($1, $2)
541
UNION
542
SELECT util.eval2set($$
543
SELECT col
544
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
545
JOIN $$||$2||$$ ON "to" = col
546
WHERE "from" LIKE ':%'
547
$$, NULL::text)
548
$_$;
549
550
551
--
552
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
553
--
554
555 12235 aaronmk
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
556
gets table_''s added columns (all the columns not in the original data)
557
';
558 10594 aaronmk
559
560
--
561 9959 aaronmk
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
562
--
563
564
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
565
    LANGUAGE sql IMMUTABLE
566
    AS $_$
567
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
568
$_$;
569
570
571
--
572
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
573
--
574
575
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
576
    LANGUAGE plpgsql IMMUTABLE
577
    AS $$
578
DECLARE
579
	value_cmp         state%TYPE = ARRAY[value];
580
	state             state%TYPE = COALESCE(state, value_cmp);
581
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
582
BEGIN
583
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
584
END;
585
$$;
586
587
588
--
589 12320 aaronmk
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
590
--
591
592
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
593
    LANGUAGE sql
594
    AS $_$
595
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
596
$_$;
597
598
599
--
600 12369 aaronmk
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
601
--
602
603
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
604
    LANGUAGE sql STRICT
605
    AS $_$
606
SELECT util.set_comment($1, concat(util.comment($1), $2))
607
$_$;
608
609
610
--
611
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
612
--
613
614
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
615
comment: must start and end with a newline
616
';
617
618
619
--
620 10305 aaronmk
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
621
--
622
623
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
624
    LANGUAGE sql IMMUTABLE
625
    AS $_$
626
SELECT pg_catalog.array_fill($1, ARRAY[$2])
627
$_$;
628
629
630
--
631 10303 aaronmk
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
632
--
633
634
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
635 10354 aaronmk
    LANGUAGE sql IMMUTABLE
636 10303 aaronmk
    AS $_$
637 10321 aaronmk
SELECT util.array_length($1, 1)
638 10303 aaronmk
$_$;
639
640
641
--
642 10304 aaronmk
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
643
--
644
645
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
646 10354 aaronmk
    LANGUAGE sql IMMUTABLE
647 10304 aaronmk
    AS $_$
648 10354 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
649 10304 aaronmk
$_$;
650
651
652
--
653
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
654
--
655
656 12235 aaronmk
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
657
returns 0 instead of NULL for empty arrays
658
';
659 10304 aaronmk
660
661
--
662 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
663 8104 aaronmk
--
664
665
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
666
    LANGUAGE sql STABLE STRICT
667
    AS $_$
668
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
669
$_$;
670
671
672
--
673 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
674 8105 aaronmk
--
675
676
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
677
    LANGUAGE plpgsql STRICT
678
    AS $_$
679
BEGIN
680
    -- not yet clustered (ARRAY[] compares NULLs literally)
681 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
682 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
683
    END IF;
684
END;
685
$_$;
686
687
688
--
689 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
690 8105 aaronmk
--
691
692 12235 aaronmk
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
693
idempotent
694
';
695 8105 aaronmk
696
697
--
698 10986 aaronmk
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
699
--
700
701
CREATE FUNCTION col__min(col col_ref) RETURNS integer
702
    LANGUAGE sql STABLE
703
    AS $_$
704
SELECT util.eval2val($$
705
SELECT $$||quote_ident($1.name)||$$
706
FROM $$||$1.table_||$$
707
ORDER BY $$||quote_ident($1.name)||$$ ASC
708
LIMIT 1
709
$$, NULL::integer)
710
$_$;
711
712
713
--
714 10136 aaronmk
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
715
--
716
717
CREATE FUNCTION col_comment(col col_ref) RETURNS text
718
    LANGUAGE plpgsql STABLE STRICT
719
    AS $$
720
DECLARE
721
	comment text;
722
BEGIN
723
	SELECT description
724
	FROM pg_attribute
725
	LEFT JOIN pg_description ON objoid = attrelid
726
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
727
	WHERE attrelid = col.table_ AND attname = col.name
728
	INTO STRICT comment
729
	;
730
	RETURN comment;
731
EXCEPTION
732
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
733
END;
734
$$;
735
736
737
--
738 10130 aaronmk
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
739
--
740
741
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
742
    LANGUAGE plpgsql STABLE STRICT
743
    AS $$
744
DECLARE
745
	default_sql text;
746
BEGIN
747
	SELECT adsrc
748
	FROM pg_attribute
749
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
750
	WHERE attrelid = col.table_ AND attname = col.name
751
	INTO STRICT default_sql
752
	;
753
	RETURN default_sql;
754
EXCEPTION
755
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
756
END;
757
$$;
758
759
760
--
761 10134 aaronmk
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
762
--
763
764
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
765
    LANGUAGE sql STABLE
766
    AS $_$
767
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
768
$_$;
769
770
771
--
772
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
773
--
774
775 12235 aaronmk
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
776
ret_type_null: NULL::ret_type
777
';
778 10134 aaronmk
779
780
--
781 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
782 8180 aaronmk
--
783
784
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
785
    LANGUAGE plpgsql STRICT
786
    AS $$
787
BEGIN
788 8183 aaronmk
    PERFORM util.col_type(col);
789 8180 aaronmk
    RETURN true;
790
EXCEPTION
791
    WHEN undefined_column THEN RETURN false;
792
END;
793
$$;
794
795
796
--
797 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
798 8084 aaronmk
--
799
800
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
801 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
802 8084 aaronmk
    AS $$
803
DECLARE
804 8183 aaronmk
    prefix text := util.name(type)||'.';
805 8084 aaronmk
BEGIN
806
    RETURN QUERY
807 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
808
        FROM util.col_names(type) f (name_);
809 8084 aaronmk
END;
810
$$;
811
812
813
--
814 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
815 8151 aaronmk
--
816
817
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
818
    LANGUAGE sql STABLE STRICT
819
    AS $_$
820
SELECT attname::text
821
FROM pg_attribute
822 10158 aaronmk
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
823 8151 aaronmk
ORDER BY attnum
824
$_$;
825
826
827
--
828 11667 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
829
--
830
831
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
832
    LANGUAGE plpgsql STABLE STRICT
833
    AS $_$
834
BEGIN
835
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
836
END;
837
$_$;
838
839
840
--
841 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
842 8106 aaronmk
--
843
844
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
845 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
846
    AS $$
847
DECLARE
848
    type regtype;
849
BEGIN
850
    SELECT atttypid FROM pg_attribute
851
    WHERE attrelid = col.table_ AND attname = col.name
852
    INTO STRICT type
853
    ;
854
    RETURN type;
855
EXCEPTION
856 8171 aaronmk
    WHEN no_data_found THEN
857 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
858
            concat('undefined column: ', col.name);
859 8169 aaronmk
END;
860
$$;
861 8106 aaronmk
862
863
--
864 12368 aaronmk
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
865
--
866
867
CREATE FUNCTION comment(element oid) RETURNS text
868
    LANGUAGE sql STABLE STRICT
869
    AS $_$
870
SELECT description FROM pg_description WHERE objoid = $1
871
$_$;
872
873
874
--
875 11005 aaronmk
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
876
--
877
878
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
879
    LANGUAGE sql IMMUTABLE
880
    AS $_$
881
SELECT util.esc_name__append($2, $1)
882
$_$;
883
884
885
--
886 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
887 8095 aaronmk
--
888
889
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
890 10388 aaronmk
    LANGUAGE sql IMMUTABLE
891 8095 aaronmk
    AS $_$
892
SELECT position($1 in $2) > 0 /*1-based offset*/
893
$_$;
894
895
896
--
897 12288 aaronmk
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
898
--
899
900
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
901
    LANGUAGE sql
902
    AS $_$
903
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
904
$_$;
905
906
907
--
908 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
909 8094 aaronmk
--
910
911
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
912
    LANGUAGE plpgsql STRICT
913
    AS $$
914
BEGIN
915 10146 aaronmk
    PERFORM util.eval(sql);
916 8094 aaronmk
EXCEPTION
917 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
918 10181 aaronmk
    WHEN duplicate_object THEN NULL; -- e.g. constraint
919 8103 aaronmk
    WHEN duplicate_column THEN NULL;
920 10244 aaronmk
    WHEN invalid_table_definition THEN
921
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
922
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
923
        END IF;
924 8094 aaronmk
END;
925
$$;
926
927
928
--
929 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
930 8094 aaronmk
--
931
932 12235 aaronmk
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
933
idempotent
934
';
935 8094 aaronmk
936
937
--
938 12378 aaronmk
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
939
--
940
941
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
942
    LANGUAGE sql IMMUTABLE
943
    AS $$
944
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
945
$$;
946
947
948
--
949 12250 aaronmk
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
950
--
951
952
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
953
    LANGUAGE sql IMMUTABLE
954
    AS $_$
955
/* newline before so the query starts at the beginning of the line.
956
newline after to visually separate queries from one another. */
957
SELECT util.raise_notice($$
958
$$||$1||$$
959
$$)
960
$_$;
961
962
963
--
964 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
965
--
966
967
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
968
    LANGUAGE sql STABLE STRICT
969
    AS $_$
970
SELECT util.eval2set($$
971
SELECT col
972
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
973
LEFT JOIN $$||$2||$$ ON "to" = col
974
WHERE "from" IS NULL
975
$$, NULL::text)
976
$_$;
977
978
979
--
980
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
981
--
982
983 12235 aaronmk
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
984
gets table_''s derived columns (all the columns not in the names table)
985
';
986 10364 aaronmk
987
988
--
989 12298 aaronmk
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
990 12044 aaronmk
--
991
992 12298 aaronmk
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
993 12044 aaronmk
    LANGUAGE sql STABLE
994
    AS $_$
995 12300 aaronmk
SELECT * FROM util.diff($1::text, $2::text, $3,
996
	util.has_single_row($1) AND util.has_single_row($2))
997 12298 aaronmk
$_$;
998
999
1000
--
1001
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1002
--
1003
1004
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1005
col_type_null (*required*): NULL::shared_base_type
1006
usage:
1007
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1008
';
1009
1010
1011
--
1012
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1013
--
1014
1015
CREATE FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1016
    LANGUAGE sql STABLE
1017
    AS $_$
1018 12044 aaronmk
SELECT * FROM
1019 12184 aaronmk
util.eval2col_pair($$
1020 12284 aaronmk
/* need to explicitly cast each side to the return type because this does not
1021
happen automatically even when an implicit cast is available */
1022
SELECT left_::$$||pg_typeof($3)||$$, right_::$$||pg_typeof($3)||$$
1023 12299 aaronmk
FROM $$||$1||$$ left_
1024
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
1025 12308 aaronmk
$$||util._if($4, ''::text, $$ON left_ = right_
1026
$$)||
1027
$$WHERE left_ IS DISTINCT FROM right_
1028 12044 aaronmk
ORDER BY left_, right_
1029 12308 aaronmk
$$, $3)
1030 12044 aaronmk
$_$;
1031
1032
1033
--
1034 12298 aaronmk
-- Name: FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1035 12280 aaronmk
--
1036
1037 12298 aaronmk
COMMENT ON FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1038 12280 aaronmk
col_type_null (*required*): NULL::col_type
1039 12299 aaronmk
single_row: whether the tables consist of a single row, which should be
1040
	displayed side-by-side
1041 12282 aaronmk
1042
to run EXPLAIN on the FULL JOIN query:
1043
# run this function
1044
# look for a NOTICE containing the expanded query that it ran
1045
# run EXPLAIN on this expanded query
1046 12280 aaronmk
';
1047
1048
1049
--
1050 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1051
--
1052
1053
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1054
    LANGUAGE sql STRICT
1055
    AS $_$
1056
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1057
$_$;
1058
1059
1060
--
1061
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1062
--
1063
1064 12235 aaronmk
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1065
idempotent
1066
';
1067 8200 aaronmk
1068
1069
--
1070 12292 aaronmk
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1071 10362 aaronmk
--
1072
1073 12292 aaronmk
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1074 10362 aaronmk
    LANGUAGE sql STRICT
1075
    AS $_$
1076
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1077 12292 aaronmk
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1078 10362 aaronmk
$_$;
1079
1080
1081
--
1082 12292 aaronmk
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1083 10362 aaronmk
--
1084
1085 12292 aaronmk
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1086 12235 aaronmk
idempotent
1087
';
1088 10362 aaronmk
1089
1090
--
1091 12331 aaronmk
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1092
--
1093
1094
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1095
    LANGUAGE sql
1096
    AS $_$
1097 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1098
included in the debug SQL */
1099
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1100 12331 aaronmk
$_$;
1101
1102
1103
--
1104 12343 aaronmk
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1105
--
1106
1107 12364 aaronmk
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1108 12343 aaronmk
    LANGUAGE sql
1109
    AS $_$
1110 12347 aaronmk
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1111 12343 aaronmk
||util._if($3, $$ CASCADE$$, ''::text))
1112
$_$;
1113
1114
1115
--
1116 12364 aaronmk
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1117 12343 aaronmk
--
1118
1119 12364 aaronmk
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1120 12343 aaronmk
idempotent
1121
';
1122
1123
1124
--
1125 12413 aaronmk
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1126
--
1127
1128
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1129
    LANGUAGE sql
1130
    AS $_$
1131
SELECT util.drop_relations_like($1, util.str_equality_regexp(util.schema($2)),
1132
$3)
1133
$_$;
1134
1135
1136
--
1137
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1138
--
1139
1140
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1141
    LANGUAGE sql
1142
    AS $_$
1143
SELECT util.drop_relation(relation, $3)
1144
FROM util.show_relations_like($1, $2) relation
1145
;
1146
SELECT NULL::void; -- don't fold away functions called in previous query
1147
$_$;
1148
1149
1150
--
1151 12292 aaronmk
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1152 10150 aaronmk
--
1153
1154 12292 aaronmk
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1155 10150 aaronmk
    LANGUAGE sql STRICT
1156
    AS $_$
1157 12347 aaronmk
SELECT util.drop_relation('TABLE', $1, $2)
1158 10150 aaronmk
$_$;
1159
1160
1161
--
1162 12292 aaronmk
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1163 10150 aaronmk
--
1164
1165 12292 aaronmk
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1166 12235 aaronmk
idempotent
1167
';
1168 10150 aaronmk
1169
1170
--
1171 12292 aaronmk
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1172 12229 aaronmk
--
1173
1174 12292 aaronmk
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1175 12229 aaronmk
    LANGUAGE sql STRICT
1176
    AS $_$
1177 12347 aaronmk
SELECT util.drop_relation('VIEW', $1, $2)
1178 12229 aaronmk
$_$;
1179
1180
1181
--
1182 12292 aaronmk
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1183 12229 aaronmk
--
1184
1185 12292 aaronmk
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1186 12235 aaronmk
idempotent
1187
';
1188 12229 aaronmk
1189
1190
--
1191 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1192
--
1193
1194
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1195
    LANGUAGE sql IMMUTABLE
1196
    AS $_$
1197
SELECT util.array_fill($1, 0)
1198
$_$;
1199
1200
1201
--
1202
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1203
--
1204
1205 12235 aaronmk
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1206
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1207
';
1208 10322 aaronmk
1209
1210
--
1211 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1212 8086 aaronmk
--
1213
1214
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1215 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1216 8086 aaronmk
    AS $_$
1217 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1218 8086 aaronmk
$_$;
1219
1220
1221
--
1222 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1223
--
1224
1225
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1226
    LANGUAGE sql IMMUTABLE
1227
    AS $_$
1228
SELECT regexp_replace($2, '("?)$', $1||'\1')
1229
$_$;
1230
1231
1232
--
1233 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1234
--
1235
1236
CREATE FUNCTION eval(sql text) RETURNS void
1237
    LANGUAGE plpgsql STRICT
1238
    AS $$
1239
BEGIN
1240 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1241
	EXECUTE sql;
1242 9824 aaronmk
END;
1243
$$;
1244
1245
1246
--
1247 12181 aaronmk
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1248
--
1249
1250
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1251
    LANGUAGE plpgsql
1252
    AS $$
1253
BEGIN
1254 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1255 12181 aaronmk
	RETURN QUERY EXECUTE sql;
1256
END;
1257
$$;
1258
1259
1260
--
1261
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1262
--
1263
1264 12235 aaronmk
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1265
col_type_null (*required*): NULL::col_type
1266
';
1267 12181 aaronmk
1268
1269
--
1270 12301 aaronmk
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1271
--
1272
1273
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1274
    LANGUAGE plpgsql
1275
    AS $$
1276
BEGIN
1277
	PERFORM util.debug_print_sql(sql);
1278
	RETURN QUERY EXECUTE sql;
1279
END;
1280
$$;
1281
1282
1283
--
1284 10363 aaronmk
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1285
--
1286
1287
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1288
    LANGUAGE plpgsql
1289
    AS $$
1290
BEGIN
1291 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1292 10363 aaronmk
	RETURN QUERY EXECUTE sql;
1293
END;
1294
$$;
1295
1296
1297
--
1298
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1299
--
1300
1301 12235 aaronmk
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1302
ret_type_null: NULL::ret_type
1303
';
1304 10363 aaronmk
1305
1306
--
1307 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1308 10128 aaronmk
--
1309
1310 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1311 10128 aaronmk
    LANGUAGE plpgsql
1312
    AS $$
1313
DECLARE
1314
	ret_val ret_type_null%TYPE;
1315
BEGIN
1316 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1317 10128 aaronmk
	EXECUTE sql INTO STRICT ret_val;
1318
	RETURN ret_val;
1319
END;
1320
$$;
1321
1322
1323
--
1324 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1325 10128 aaronmk
--
1326
1327 12235 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1328
ret_type_null: NULL::ret_type
1329
';
1330 10128 aaronmk
1331
1332
--
1333 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1334
--
1335
1336
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1337
    LANGUAGE sql
1338
    AS $_$
1339 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1340 10131 aaronmk
$_$;
1341
1342
1343
--
1344
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1345
--
1346
1347 12235 aaronmk
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1348
ret_type_null: NULL::ret_type
1349
';
1350 10131 aaronmk
1351
1352
--
1353 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1354
--
1355
1356
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1357
    LANGUAGE sql
1358
    AS $_$
1359
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1360
$_$;
1361
1362
1363
--
1364
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1365
--
1366
1367 12235 aaronmk
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1368
sql: can be NULL, which will be passed through
1369
ret_type_null: NULL::ret_type
1370
';
1371 10133 aaronmk
1372
1373
--
1374 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1375 8182 aaronmk
--
1376
1377
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1378
    LANGUAGE sql STABLE STRICT
1379
    AS $_$
1380
SELECT col_name
1381
FROM unnest($2) s (col_name)
1382 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1383 8182 aaronmk
$_$;
1384
1385
1386
--
1387 11830 aaronmk
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1388
--
1389
1390
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1391
    LANGUAGE sql
1392
    AS $_$
1393
SELECT util.eval2set($$EXPLAIN $$||$1)
1394
$_$;
1395
1396
1397
--
1398 11833 aaronmk
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1399
--
1400
1401
CREATE FUNCTION explain2notice(sql text) RETURNS void
1402
    LANGUAGE plpgsql
1403
    AS $_$
1404
BEGIN
1405
	RAISE NOTICE '%', $$EXPLAIN:
1406
$$||util.explain2str(sql);
1407
END;
1408
$_$;
1409
1410
1411
--
1412 11832 aaronmk
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1413
--
1414
1415
CREATE FUNCTION explain2str(sql text) RETURNS text
1416
    LANGUAGE sql
1417
    AS $_$
1418
SELECT util.join_strs(explain, $$
1419
$$) FROM util.explain($1)
1420
$_$;
1421
1422
1423 11835 aaronmk
SET default_tablespace = '';
1424
1425
SET default_with_oids = false;
1426
1427 11832 aaronmk
--
1428 11835 aaronmk
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace:
1429 11831 aaronmk
--
1430
1431 11835 aaronmk
CREATE TABLE explain (
1432
    line text NOT NULL
1433
);
1434
1435
1436
--
1437
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1438
--
1439
1440
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1441 11831 aaronmk
    LANGUAGE sql
1442
    AS $_$
1443 11835 aaronmk
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1444
$$||quote_nullable($1)||$$
1445 11831 aaronmk
)$$)
1446
$_$;
1447
1448
1449
--
1450 11836 aaronmk
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1451
--
1452
1453 12235 aaronmk
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1454
usage:
1455 11836 aaronmk
PERFORM util.explain2table($$
1456
query
1457 12235 aaronmk
$$);
1458
';
1459 11836 aaronmk
1460
1461
--
1462 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1463
--
1464
1465
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1466 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1467 10323 aaronmk
    AS $_$
1468 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1469
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1470
) END
1471 10323 aaronmk
$_$;
1472
1473
1474
--
1475
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1476
--
1477
1478 12235 aaronmk
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1479
ensures that an array will always have proper non-NULL dimensions
1480
';
1481 10323 aaronmk
1482
1483
--
1484 11695 aaronmk
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1485
--
1486
1487
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1488
    LANGUAGE plpgsql
1489
    AS $_$
1490
DECLARE
1491
	PG_EXCEPTION_DETAIL text;
1492
	recreate_users_cmd text = util.save_drop_views(users);
1493
BEGIN
1494
	PERFORM util.eval(cmd);
1495
	PERFORM util.eval(recreate_users_cmd);
1496
EXCEPTION
1497
WHEN dependent_objects_still_exist THEN
1498
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1499
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1500
	users = array(SELECT * FROM util.regexp_matches_group(
1501
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1502
	IF util.is_empty(users) THEN RAISE; END IF;
1503
	PERFORM util.force_recreate(cmd, users);
1504
END;
1505
$_$;
1506
1507
1508
--
1509
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1510
--
1511
1512 12235 aaronmk
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1513
idempotent
1514 11695 aaronmk
1515 12235 aaronmk
users: not necessary to provide this because it will be autopopulated
1516
';
1517 11695 aaronmk
1518
1519
--
1520 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1521
--
1522
1523
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1524
    LANGUAGE plpgsql STRICT
1525
    AS $_$
1526
DECLARE
1527
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1528
$$||query;
1529
BEGIN
1530
	EXECUTE mk_view;
1531
EXCEPTION
1532
WHEN invalid_table_definition THEN
1533 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1534
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1535
	THEN
1536 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1537
		EXECUTE mk_view;
1538
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1539
	END IF;
1540
END;
1541
$_$;
1542
1543
1544
--
1545
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1546
--
1547
1548 12235 aaronmk
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1549
idempotent
1550
';
1551 8321 aaronmk
1552
1553
--
1554 11655 aaronmk
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1555
--
1556
1557
CREATE FUNCTION grants_users() RETURNS SETOF text
1558
    LANGUAGE sql IMMUTABLE
1559
    AS $$
1560
VALUES ('bien_read'), ('public_')
1561
$$;
1562
1563
1564
--
1565 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1566 8085 aaronmk
--
1567
1568
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1569 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1570 8085 aaronmk
    AS $_$
1571
SELECT substring($2 for length($1)) = $1
1572
$_$;
1573
1574
1575
--
1576 12296 aaronmk
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1577
--
1578
1579
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1580
    LANGUAGE sql STABLE
1581
    AS $_$
1582
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1583
$_$;
1584
1585
1586
--
1587 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1588
--
1589
1590
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1591
    LANGUAGE sql IMMUTABLE
1592
    AS $_$
1593 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1594 10307 aaronmk
$_$;
1595
1596
1597
--
1598
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1599
--
1600
1601 12235 aaronmk
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1602
avoids repeating the same value for each key
1603
';
1604 10307 aaronmk
1605
1606
--
1607 12218 aaronmk
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1608
--
1609
1610
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1611
    LANGUAGE sql IMMUTABLE
1612
    AS $_$
1613 12222 aaronmk
SELECT COALESCE($1, $2)
1614 12218 aaronmk
$_$;
1615
1616
1617
--
1618
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1619
--
1620
1621 12235 aaronmk
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1622
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1623
';
1624 12218 aaronmk
1625
1626
--
1627 12285 aaronmk
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1628
--
1629
1630
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1631
    LANGUAGE sql
1632
    AS $_$
1633
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1634
$_$;
1635
1636
1637
--
1638 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1639
--
1640
1641
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1642
    LANGUAGE sql STABLE STRICT
1643
    AS $_$
1644
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1645
$_$;
1646
1647
1648
--
1649 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1650
--
1651
1652
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1653
    LANGUAGE sql IMMUTABLE
1654
    AS $_$
1655
SELECT util.array_length($1) = 0
1656
$_$;
1657
1658
1659
--
1660 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1661
--
1662
1663
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1664
    LANGUAGE sql IMMUTABLE
1665
    AS $_$
1666
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1667
$_$;
1668
1669
1670
--
1671 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1672
--
1673
1674
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1675
    LANGUAGE sql IMMUTABLE
1676
    AS $_$
1677
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1678
$_$;
1679
1680
1681
--
1682 12330 aaronmk
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1683
--
1684
1685
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1686 12332 aaronmk
    LANGUAGE sql STABLE
1687 12330 aaronmk
    AS $_$
1688
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1689
$_$;
1690
1691
1692
--
1693 12329 aaronmk
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1694
--
1695
1696
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1697 12332 aaronmk
    LANGUAGE sql STABLE
1698 12329 aaronmk
    AS $_$
1699
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1700
$_$;
1701
1702
1703
--
1704 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1705 4009 aaronmk
--
1706
1707 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1708 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1709 4009 aaronmk
    AS $_$
1710 4054 aaronmk
SELECT $1 || $3 || $2
1711 2595 aaronmk
$_$;
1712
1713
1714
--
1715 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1716 10985 aaronmk
--
1717
1718 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1719 10985 aaronmk
    LANGUAGE sql IMMUTABLE
1720
    AS $_$
1721 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1722 10985 aaronmk
$_$;
1723
1724
1725
--
1726 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1727
--
1728
1729
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1730
    LANGUAGE sql IMMUTABLE
1731
    AS $_$
1732
SELECT ltrim($1, $$
1733
$$)
1734
$_$;
1735
1736
1737
--
1738 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1739
--
1740
1741
CREATE FUNCTION map_filter_insert() RETURNS trigger
1742
    LANGUAGE plpgsql
1743
    AS $$
1744
BEGIN
1745
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1746
	RETURN new;
1747
END;
1748
$$;
1749
1750
1751
--
1752 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1753 8146 aaronmk
--
1754
1755
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1756
    LANGUAGE plpgsql STABLE STRICT
1757
    AS $_$
1758
DECLARE
1759
    value text;
1760
BEGIN
1761
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1762 8149 aaronmk
        INTO value USING key;
1763 8146 aaronmk
    RETURN value;
1764
END;
1765
$_$;
1766
1767
1768
--
1769 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1770 10325 aaronmk
--
1771
1772 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1773 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1774 10325 aaronmk
    AS $_$
1775 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1776 10325 aaronmk
$_$;
1777
1778
1779
--
1780 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1781
--
1782
1783 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
1784
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
1785 10359 aaronmk
1786
[1] inlining of function calls, which is different from constant folding
1787
[2] _map()''s profiling query
1788
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1789
and map_nulls()''s profiling query
1790
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1791 10375 aaronmk
both take ~920 ms.
1792 12235 aaronmk
also, /inputs/REMIB/Specimen/postprocess.sql > country takes the same amount of time (56000 ms) to build with map_nulls() as with a literal hstore.
1793
';
1794 10359 aaronmk
1795
1796
--
1797 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1798 8150 aaronmk
--
1799
1800
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1801
    LANGUAGE plpgsql STABLE STRICT
1802
    AS $_$
1803
BEGIN
1804
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1805
END;
1806
$_$;
1807
1808
1809
--
1810 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1811
--
1812
1813 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1814 12228 aaronmk
    LANGUAGE sql
1815
    AS $_$
1816 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1817 12321 aaronmk
$$||util.ltrim_nl($2));
1818
-- make sure the created table has the correct estimated row count
1819
SELECT util.analyze_($1);
1820 12228 aaronmk
$_$;
1821
1822
1823
--
1824 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1825 12228 aaronmk
--
1826
1827 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1828 12235 aaronmk
idempotent
1829
';
1830 12228 aaronmk
1831
1832
--
1833 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1834
--
1835
1836 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1837 12234 aaronmk
    LANGUAGE sql
1838
    AS $_$
1839
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1840
$_$;
1841
1842
1843
--
1844 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1845 12234 aaronmk
--
1846
1847 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1848 12235 aaronmk
idempotent
1849
';
1850 12234 aaronmk
1851
1852
--
1853 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1854
--
1855
1856
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1857
    LANGUAGE sql STRICT
1858
    AS $_$
1859 10135 aaronmk
SELECT util.create_if_not_exists($$
1860
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1861 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1862 10135 aaronmk
||quote_literal($2)||$$;
1863 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1864
constant
1865
';
1866 10135 aaronmk
$$)
1867 8190 aaronmk
$_$;
1868
1869
1870
--
1871
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1872
--
1873
1874 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1875
idempotent
1876
';
1877 8190 aaronmk
1878
1879
--
1880 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1881 8187 aaronmk
--
1882
1883 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1884 8187 aaronmk
    LANGUAGE plpgsql STRICT
1885
    AS $_$
1886
DECLARE
1887
    type regtype = util.typeof(expr, col.table_::text::regtype);
1888
    col_name_sql text = quote_ident(col.name);
1889
BEGIN
1890 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1891
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1892 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1893
$$||expr||$$;
1894
$$);
1895
END;
1896
$_$;
1897
1898
1899
--
1900 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1901 8188 aaronmk
--
1902
1903 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1904
idempotent
1905
';
1906 8188 aaronmk
1907
1908
--
1909 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1910 8139 aaronmk
--
1911
1912
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1913 8141 aaronmk
    LANGUAGE sql STRICT
1914 8139 aaronmk
    AS $_$
1915 8183 aaronmk
SELECT util.create_if_not_exists($$
1916 8141 aaronmk
CREATE TABLE $$||$1||$$
1917 8139 aaronmk
(
1918 8183 aaronmk
    LIKE util.map INCLUDING ALL
1919 10110 aaronmk
);
1920
1921
CREATE TRIGGER map_filter_insert
1922
  BEFORE INSERT
1923
  ON $$||$1||$$
1924
  FOR EACH ROW
1925
  EXECUTE PROCEDURE util.map_filter_insert();
1926 8141 aaronmk
$$)
1927 8139 aaronmk
$_$;
1928
1929
1930
--
1931 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1932
--
1933
1934
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1935
    LANGUAGE sql IMMUTABLE
1936
    AS $_$
1937
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1938
$_$;
1939
1940
1941
--
1942 12272 aaronmk
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1943
--
1944
1945
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1946
    LANGUAGE sql IMMUTABLE
1947
    AS $_$
1948
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1949
$_$;
1950
1951
1952
--
1953
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1954
--
1955
1956
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1957
usage:
1958
for *1* schema arg:
1959
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1960
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1961
';
1962
1963
1964
--
1965 12270 aaronmk
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1966
--
1967
1968
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1969
    LANGUAGE sql IMMUTABLE
1970
    AS $_$
1971
SELECT $$SET LOCAL search_path TO $$||$1
1972
$_$;
1973
1974
1975
--
1976 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1977
--
1978
1979
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1980
    LANGUAGE sql STRICT
1981
    AS $_$
1982 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1983 10113 aaronmk
$_$;
1984
1985
1986
--
1987
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1988
--
1989
1990 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1991
idempotent
1992
';
1993 10113 aaronmk
1994
1995
--
1996 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1997
--
1998
1999
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2000
    LANGUAGE plpgsql STRICT
2001
    AS $_$
2002
DECLARE
2003
	view_qual_name text = util.qual_name(view_);
2004
BEGIN
2005
	EXECUTE $$
2006
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2007
  RETURNS SETOF $$||view_||$$ AS
2008
$BODY1$
2009
SELECT * FROM $$||view_qual_name||$$
2010
ORDER BY sort_col
2011
LIMIT $1 OFFSET $2
2012
$BODY1$
2013
  LANGUAGE sql STABLE
2014
  COST 100
2015
  ROWS 1000
2016
$$;
2017
2018
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2019
END;
2020
$_$;
2021
2022
2023
--
2024 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2025
--
2026
2027
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2028
    LANGUAGE plpgsql STRICT
2029
    AS $_$
2030 10990 aaronmk
DECLARE
2031
	view_qual_name text = util.qual_name(view_);
2032
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2033 8325 aaronmk
BEGIN
2034
	EXECUTE $$
2035 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2036
  RETURNS integer AS
2037
$BODY1$
2038
SELECT $$||quote_ident(row_num_col)||$$
2039
FROM $$||view_qual_name||$$
2040
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2041
LIMIT 1
2042
$BODY1$
2043
  LANGUAGE sql STABLE
2044
  COST 100;
2045
$$;
2046
2047
	EXECUTE $$
2048 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2049
  RETURNS SETOF $$||view_||$$ AS
2050
$BODY1$
2051 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
2052
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2053
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2054
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2055 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
2056 8325 aaronmk
$BODY1$
2057
  LANGUAGE sql STABLE
2058
  COST 100
2059
  ROWS 1000
2060
$$;
2061 11010 aaronmk
2062
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2063
END;
2064
$_$;
2065
2066
2067
--
2068
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2069
--
2070
2071
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2072
    LANGUAGE plpgsql STRICT
2073
    AS $_$
2074
DECLARE
2075
	view_qual_name text = util.qual_name(view_);
2076
BEGIN
2077 8326 aaronmk
	EXECUTE $$
2078
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2079
  RETURNS SETOF $$||view_||$$
2080
  SET enable_sort TO 'off'
2081
  AS
2082
$BODY1$
2083 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
2084 8326 aaronmk
$BODY1$
2085
  LANGUAGE sql STABLE
2086
  COST 100
2087
  ROWS 1000
2088
;
2089
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2090
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2091
If you want to run EXPLAIN and get expanded output, use the regular subset
2092
function instead. (When a config param is set on a function, EXPLAIN produces
2093
just a function scan.)
2094
';
2095
$$;
2096 8325 aaronmk
END;
2097
$_$;
2098
2099
2100
--
2101 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2102
--
2103
2104 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2105
creates subset function which turns off enable_sort
2106
';
2107 11010 aaronmk
2108
2109
--
2110 12271 aaronmk
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2111
--
2112
2113
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2114
    LANGUAGE sql IMMUTABLE
2115
    AS $_$
2116
SELECT util.mk_set_search_path(util.schema_esc($1))
2117
$_$;
2118
2119
2120
--
2121 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2122
--
2123
2124
CREATE FUNCTION name(table_ regclass) RETURNS text
2125
    LANGUAGE sql STABLE
2126
    AS $_$
2127
SELECT relname::text FROM pg_class WHERE oid = $1
2128
$_$;
2129
2130
2131
--
2132 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2133 8083 aaronmk
--
2134
2135
CREATE FUNCTION name(type regtype) RETURNS text
2136 8097 aaronmk
    LANGUAGE sql STABLE STRICT
2137 8083 aaronmk
    AS $_$
2138
SELECT typname::text FROM pg_type WHERE oid = $1
2139
$_$;
2140
2141
2142
--
2143 12360 aaronmk
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2144 12355 aaronmk
--
2145
2146 12360 aaronmk
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2147 12355 aaronmk
    LANGUAGE sql IMMUTABLE
2148
    AS $_$
2149 12360 aaronmk
SELECT octet_length($1) >= util.namedatalen() - $2
2150 12355 aaronmk
$_$;
2151
2152
2153
--
2154 12354 aaronmk
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2155
--
2156
2157
CREATE FUNCTION namedatalen() RETURNS integer
2158
    LANGUAGE sql IMMUTABLE
2159
    AS $$
2160
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2161
$$;
2162
2163
2164
--
2165 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2166
--
2167
2168
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2169
    LANGUAGE sql IMMUTABLE
2170
    AS $_$
2171 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2172 9958 aaronmk
$_$;
2173
2174
2175
--
2176 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2177
--
2178
2179
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2180 9957 aaronmk
    LANGUAGE sql IMMUTABLE
2181 9956 aaronmk
    AS $_$
2182
SELECT $1 IS NOT NULL
2183
$_$;
2184
2185
2186
--
2187 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2188
--
2189
2190
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2191
    LANGUAGE sql IMMUTABLE
2192
    AS $_$
2193
SELECT util.hstore($1, NULL) || '*=>*'
2194
$_$;
2195
2196
2197
--
2198
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2199
--
2200
2201 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2202
for use with _map()
2203
';
2204 10373 aaronmk
2205
2206
--
2207 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2208 10984 aaronmk
--
2209
2210 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2211 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2212
    AS $_$
2213 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2214 10984 aaronmk
$_$;
2215
2216
2217
--
2218 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2219
--
2220
2221
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2222
    LANGUAGE sql IMMUTABLE
2223
    AS $_$
2224
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2225
$_$;
2226
2227
2228
--
2229 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2230
--
2231
2232
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2233 12267 aaronmk
    LANGUAGE sql STABLE STRICT
2234
    SET search_path TO pg_temp
2235 10988 aaronmk
    AS $_$
2236 12267 aaronmk
SELECT $1::text
2237 10988 aaronmk
$_$;
2238
2239
2240
--
2241 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2242
--
2243
2244
CREATE FUNCTION qual_name(type regtype) RETURNS text
2245
    LANGUAGE sql STABLE STRICT
2246
    SET search_path TO pg_temp
2247
    AS $_$
2248
SELECT $1::text
2249
$_$;
2250
2251
2252
--
2253
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2254
--
2255
2256
COMMENT ON FUNCTION qual_name(type regtype) IS '
2257
a type''s schema-qualified name
2258
';
2259
2260
2261
--
2262 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2263
--
2264
2265
CREATE FUNCTION qual_name(type unknown) RETURNS text
2266
    LANGUAGE sql STABLE STRICT
2267
    AS $_$
2268
SELECT util.qual_name($1::text::regtype)
2269
$_$;
2270
2271
2272
--
2273 12376 aaronmk
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2274
--
2275
2276
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2277
    LANGUAGE sql IMMUTABLE
2278
    AS $_$
2279
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2280
$_$;
2281
2282
2283
--
2284
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2285
--
2286
2287
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2288
    LANGUAGE sql IMMUTABLE
2289
    AS $_$
2290
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2291
$_$;
2292
2293
2294
--
2295 12371 aaronmk
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2296
--
2297
2298
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2299
    LANGUAGE sql IMMUTABLE
2300
    AS $_$
2301
SELECT quote_nullable($1)||$$::$$||pg_typeof($1)
2302
$_$;
2303
2304
2305
--
2306 12311 aaronmk
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2307
--
2308
2309
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2310
    LANGUAGE sql IMMUTABLE STRICT
2311
    AS $_$
2312
SELECT util.raise_notice('ERROR:  '||$1)
2313
$_$;
2314
2315
2316
--
2317 12249 aaronmk
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2318
--
2319
2320
CREATE FUNCTION raise_notice(msg text) RETURNS void
2321
    LANGUAGE plpgsql IMMUTABLE STRICT
2322
    AS $$
2323
BEGIN
2324
	RAISE NOTICE '%', msg;
2325
END;
2326
$$;
2327
2328
2329
--
2330 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2331
--
2332
2333
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2334
    LANGUAGE plpgsql IMMUTABLE STRICT
2335
    AS $$
2336
BEGIN
2337
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2338
END;
2339
$$;
2340
2341
2342
--
2343 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2344
--
2345
2346
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2347
    LANGUAGE sql IMMUTABLE
2348
    AS $_$
2349
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2350
$_$;
2351
2352
2353
--
2354 12333 aaronmk
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2355
--
2356
2357
CREATE FUNCTION regexp_quote(str text) RETURNS text
2358
    LANGUAGE sql IMMUTABLE
2359
    AS $_$
2360
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2361
$_$;
2362
2363
2364
--
2365 12375 aaronmk
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2366
--
2367
2368
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2369
    LANGUAGE sql IMMUTABLE
2370
    AS $_$
2371
SELECT (CASE WHEN right($1, 1) = ')'
2372 12377 aaronmk
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2373 12375 aaronmk
$_$;
2374
2375
2376
--
2377 12344 aaronmk
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2378
--
2379
2380
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2381
    LANGUAGE sql STABLE
2382
    AS $_$
2383
SELECT util.relation_type(util.relation_type_char($1))
2384
$_$;
2385
2386
2387
--
2388 12340 aaronmk
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2389 12339 aaronmk
--
2390
2391 12340 aaronmk
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2392 12339 aaronmk
    LANGUAGE sql IMMUTABLE
2393
    AS $_$
2394
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2395
$_$;
2396
2397
2398
--
2399 12341 aaronmk
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2400
--
2401
2402
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2403
    LANGUAGE sql STABLE
2404
    AS $_$
2405
SELECT relkind FROM pg_class WHERE oid = $1
2406
$_$;
2407
2408
2409
--
2410 12293 aaronmk
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2411
--
2412
2413
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2414
    LANGUAGE sql
2415
    AS $_$
2416
/* can't have in_table/out_table inherit from *each other*, because inheritance
2417
also causes the rows of the parent table to be included in the child table.
2418
instead, they need to inherit from a common, empty table. */
2419 12382 aaronmk
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2420
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2421 12293 aaronmk
SELECT util.inherit($2, $4);
2422
SELECT util.inherit($3, $4);
2423
2424
SELECT util.rematerialize_query($1, $$
2425
SELECT * FROM util.diff(
2426 12297 aaronmk
  $$||quote_nullable($2)||$$::regclass
2427
, $$||quote_nullable($3)||$$::regclass
2428 12293 aaronmk
, NULL::$$||$4||$$)
2429
$$);
2430 12303 aaronmk
2431
/* the table unfortunately cannot be *materialized* in human-readable form,
2432
because this would create column name collisions between the two sides */
2433 12370 aaronmk
SELECT util.append_comment($1, '
2434 12303 aaronmk
to view this table in human-readable form (with each side''s tuple column
2435
expanded to its component fields):
2436
SELECT (left_).*, (right_).* FROM '||$1||';
2437
');
2438 12293 aaronmk
$_$;
2439
2440
2441
--
2442
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2443
--
2444
2445
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2446
type_table (*required*): table to create as the shared base type
2447
';
2448
2449
2450
--
2451 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2452
--
2453
2454
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2455
    LANGUAGE sql
2456
    AS $_$
2457
SELECT util.drop_table($1);
2458
SELECT util.materialize_query($1, $2);
2459
$_$;
2460
2461
2462
--
2463
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2464
--
2465
2466
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2467
idempotent, but repeats action each time
2468
';
2469
2470
2471
--
2472 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2473
--
2474
2475 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2476 12247 aaronmk
    LANGUAGE sql
2477
    AS $_$
2478
SELECT util.drop_table($1);
2479
SELECT util.materialize_view($1, $2);
2480
$_$;
2481
2482
2483
--
2484 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2485 12247 aaronmk
--
2486
2487 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2488 12247 aaronmk
idempotent, but repeats action each time
2489
';
2490
2491
2492
--
2493 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2494 8137 aaronmk
--
2495
2496 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2497 8137 aaronmk
    LANGUAGE sql STRICT
2498
    AS $_$
2499 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2500 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2501 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
2502
SELECT NULL::void; -- don't fold away functions called in previous query
2503 8137 aaronmk
$_$;
2504
2505
2506
--
2507 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2508 8137 aaronmk
--
2509
2510 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2511
idempotent
2512
';
2513 8137 aaronmk
2514
2515
--
2516 12349 aaronmk
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2517
--
2518
2519
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2520
    LANGUAGE sql
2521
    AS $_$
2522 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2523
included in the debug SQL */
2524
SELECT util.rename_relation(util.qual_name($1), $2)
2525 12349 aaronmk
$_$;
2526
2527
2528
--
2529
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2530
--
2531
2532 12364 aaronmk
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2533 12349 aaronmk
    LANGUAGE sql
2534
    AS $_$
2535
/* 'ALTER TABLE can be used with views too'
2536
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2537 12363 aaronmk
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2538
||quote_ident($2))
2539 12349 aaronmk
$_$;
2540
2541
2542
--
2543 12364 aaronmk
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2544 12349 aaronmk
--
2545
2546 12364 aaronmk
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2547 12349 aaronmk
idempotent
2548
';
2549
2550
2551
--
2552 12358 aaronmk
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2553 12350 aaronmk
--
2554
2555 12358 aaronmk
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2556 12350 aaronmk
    LANGUAGE sql IMMUTABLE
2557
    AS $_$
2558 12358 aaronmk
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2559 12350 aaronmk
$_$;
2560
2561
2562
--
2563 12358 aaronmk
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2564
--
2565
2566
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2567
max_prefix_len: when str may have been truncated (eg. as a table name) due to the prepending of a prefix, support prefixes up to this length
2568
';
2569
2570
2571
--
2572 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2573
--
2574
2575
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2576
    LANGUAGE sql STRICT
2577
    AS $_$
2578 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2579
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2580 10297 aaronmk
SELECT util.set_col_names($1, $2);
2581
$_$;
2582
2583
2584
--
2585
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2586
--
2587
2588 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2589
idempotent.
2590
alters the names table, so it will need to be repopulated after running this function.
2591
';
2592 10297 aaronmk
2593
2594
--
2595 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2596 8143 aaronmk
--
2597
2598
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2599
    LANGUAGE sql STRICT
2600
    AS $_$
2601 10152 aaronmk
SELECT util.drop_table($1);
2602 8183 aaronmk
SELECT util.mk_map_table($1);
2603 8143 aaronmk
$_$;
2604
2605
2606
--
2607 12356 aaronmk
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2608
--
2609
2610
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2611
    LANGUAGE sql IMMUTABLE
2612
    AS $_$
2613
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2614
$_$;
2615
2616
2617
--
2618 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2619
--
2620
2621
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2622
    LANGUAGE plpgsql STRICT
2623
    AS $_$
2624
DECLARE
2625
	result text = NULL;
2626
BEGIN
2627
	BEGIN
2628
		result = util.show_create_view(view_);
2629
		PERFORM util.eval($$DROP VIEW $$||view_);
2630
	EXCEPTION
2631
		WHEN undefined_table THEN NULL;
2632
	END;
2633
	RETURN result;
2634
END;
2635
$_$;
2636
2637
2638
--
2639 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2640
--
2641
2642
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2643
    LANGUAGE sql
2644
    AS $_$
2645 12269 aaronmk
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2646 11660 aaronmk
$_$;
2647
2648
2649
--
2650 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2651
--
2652
2653
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2654
    LANGUAGE sql STABLE
2655
    AS $_$
2656
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2657
$_$;
2658
2659
2660
--
2661 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2662
--
2663
2664
CREATE FUNCTION schema(table_ regclass) RETURNS text
2665
    LANGUAGE sql STABLE
2666
    AS $_$
2667 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2668 12242 aaronmk
$_$;
2669
2670
2671
--
2672 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2673
--
2674
2675
CREATE FUNCTION schema(type regtype) RETURNS text
2676
    LANGUAGE sql STABLE
2677
    AS $_$
2678 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2679 10794 aaronmk
$_$;
2680
2681
2682
--
2683
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2684
--
2685
2686
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2687
    LANGUAGE sql STABLE
2688
    AS $_$
2689
SELECT util.schema(pg_typeof($1))
2690
$_$;
2691
2692
2693
--
2694 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2695
--
2696
2697
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2698
    LANGUAGE sql STABLE
2699
    AS $_$
2700
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2701
$_$;
2702
2703
2704
--
2705 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2706
--
2707
2708 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2709
a schema bundle is a group of schemas with a common prefix
2710
';
2711 12135 aaronmk
2712
2713
--
2714
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2715
--
2716
2717
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2718
    LANGUAGE sql
2719
    AS $_$
2720
SELECT util.schema_rename(old_schema,
2721
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2722
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2723
SELECT NULL::void; -- don't fold away functions called in previous query
2724
$_$;
2725
2726
2727
--
2728
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2729
--
2730
2731
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2732
    LANGUAGE plpgsql
2733
    AS $$
2734
BEGIN
2735
	-- don't schema_bundle_rm() the schema_bundle to keep!
2736
	IF replace = with_ THEN RETURN; END IF;
2737
2738
	PERFORM util.schema_bundle_rm(replace);
2739
	PERFORM util.schema_bundle_rename(with_, replace);
2740
END;
2741
$$;
2742
2743
2744
--
2745
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2746
--
2747
2748
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2749
    LANGUAGE sql
2750
    AS $_$
2751
SELECT util.schema_rm(schema)
2752
FROM util.schema_bundle_get_schemas($1) f (schema);
2753
SELECT NULL::void; -- don't fold away functions called in previous query
2754
$_$;
2755
2756
2757
--
2758 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2759 10795 aaronmk
--
2760
2761 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2762 10795 aaronmk
    LANGUAGE sql STABLE
2763
    AS $_$
2764
SELECT quote_ident(util.schema($1))
2765
$_$;
2766
2767
2768
--
2769 12324 aaronmk
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2770
--
2771
2772
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2773 12334 aaronmk
    LANGUAGE sql IMMUTABLE
2774 12324 aaronmk
    AS $_$
2775
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2776
$_$;
2777
2778
2779
--
2780 12304 aaronmk
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2781
--
2782
2783
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2784
    LANGUAGE sql STABLE
2785
    AS $_$
2786
SELECT oid FROM pg_namespace WHERE nspname = $1
2787
$_$;
2788
2789
2790
--
2791 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2792
--
2793
2794
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2795
    LANGUAGE sql
2796
    AS $_$
2797
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2798
$_$;
2799
2800
2801
--
2802 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2803
--
2804
2805
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2806
    LANGUAGE plpgsql
2807
    AS $$
2808
BEGIN
2809
	-- don't schema_rm() the schema to keep!
2810
	IF replace = with_ THEN RETURN; END IF;
2811
2812
	PERFORM util.schema_rm(replace);
2813
	PERFORM util.schema_rename(with_, replace);
2814
END;
2815
$$;
2816
2817
2818
--
2819 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2820
--
2821
2822
CREATE FUNCTION schema_rm(schema text) RETURNS void
2823
    LANGUAGE sql
2824
    AS $_$
2825
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2826
$_$;
2827
2828
2829
--
2830 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2831
--
2832
2833
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2834
    LANGUAGE sql STRICT
2835
    AS $_$
2836
SELECT util.eval(
2837
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2838
$_$;
2839
2840
2841
--
2842 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2843 8153 aaronmk
--
2844
2845
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2846
    LANGUAGE plpgsql STRICT
2847
    AS $_$
2848
DECLARE
2849 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
2850
    new text[] = ARRAY(SELECT util.map_values(names));
2851 8153 aaronmk
BEGIN
2852
    old = old[1:array_length(new, 1)]; -- truncate to same length
2853 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2854
||$$ TO $$||quote_ident(value))
2855 10149 aaronmk
    FROM each(hstore(old, new))
2856
    WHERE value != key -- not same name
2857
    ;
2858 8153 aaronmk
END;
2859
$_$;
2860
2861
2862
--
2863 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2864 8153 aaronmk
--
2865
2866 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2867
idempotent
2868
';
2869 8153 aaronmk
2870
2871
--
2872 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2873
--
2874
2875
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2876
    LANGUAGE plpgsql STRICT
2877
    AS $_$
2878
DECLARE
2879
	row_ util.map;
2880
BEGIN
2881 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
2882
	BEGIN
2883
		PERFORM util.set_col_names(table_, names);
2884
	EXCEPTION
2885
		WHEN array_subscript_error THEN -- selective suppress
2886
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2887
				-- metadata cols not yet added
2888
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2889
			END IF;
2890
	END;
2891
2892 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2893 10145 aaronmk
	LOOP
2894 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
2895
			substring(row_."from" from 2));
2896 10145 aaronmk
	END LOOP;
2897
2898
	PERFORM util.set_col_names(table_, names);
2899
END;
2900
$_$;
2901
2902
2903
--
2904
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2905
--
2906
2907 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2908
idempotent.
2909
the metadata mappings must be *last* in the names table.
2910
';
2911 10145 aaronmk
2912
2913
--
2914 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2915 8107 aaronmk
--
2916
2917
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2918
    LANGUAGE plpgsql STRICT
2919
    AS $_$
2920
DECLARE
2921
    sql text = $$ALTER TABLE $$||table_||$$
2922
$$||NULLIF(array_to_string(ARRAY(
2923
    SELECT
2924
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2925
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2926
    FROM
2927
    (
2928
        SELECT
2929
          quote_ident(col_name) AS col_name_sql
2930 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
2931 8107 aaronmk
        , type AS target_type
2932
        FROM unnest(col_casts)
2933
    ) s
2934
    WHERE curr_type != target_type
2935
), '
2936
, '), '');
2937
BEGIN
2938 12251 aaronmk
    PERFORM util.debug_print_sql(sql);
2939 8107 aaronmk
    EXECUTE COALESCE(sql, '');
2940
END;
2941
$_$;
2942
2943
2944
--
2945 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2946 8107 aaronmk
--
2947
2948 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2949
idempotent
2950
';
2951 8107 aaronmk
2952
2953
--
2954 12302 aaronmk
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2955
--
2956
2957
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2958
    LANGUAGE sql STRICT
2959
    AS $_$
2960
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2961
$_$;
2962
2963
2964
--
2965 11651 aaronmk
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2966
--
2967
2968
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2969
    LANGUAGE sql STABLE
2970
    AS $_$
2971 11656 aaronmk
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2972
$$||util.show_grants_for($1)
2973 11651 aaronmk
$_$;
2974
2975
2976
--
2977 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2978
--
2979
2980
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2981
    LANGUAGE sql STABLE
2982
    AS $_$
2983 12269 aaronmk
SELECT string_agg(cmd, '')
2984 11655 aaronmk
FROM
2985
(
2986
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2987
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2988
$$ ELSE '' END) AS cmd
2989
	FROM util.grants_users() f (user_)
2990
) s
2991
$_$;
2992
2993
2994
--
2995 12325 aaronmk
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2996
--
2997
2998
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
2999
    LANGUAGE sql STABLE
3000
    AS $_$
3001
SELECT oid FROM pg_class
3002
WHERE relkind = ANY($3) AND relname ~ $1
3003
AND util.schema_matches(util.schema(relnamespace), $2)
3004
ORDER BY relname
3005
$_$;
3006
3007
3008
--
3009 12305 aaronmk
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3010
--
3011
3012 12385 aaronmk
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3013 12305 aaronmk
    LANGUAGE sql STABLE
3014
    AS $_$
3015 12385 aaronmk
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3016 12305 aaronmk
$_$;
3017
3018
3019
--
3020 12384 aaronmk
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3021
--
3022
3023
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3024
    LANGUAGE sql IMMUTABLE
3025
    AS $_$
3026
SELECT '^'||util.regexp_quote($1)||'$'
3027
$_$;
3028
3029
3030
--
3031 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3032 8144 aaronmk
--
3033
3034
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3035 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
3036 8144 aaronmk
    AS $_$
3037
DECLARE
3038
    hstore hstore;
3039
BEGIN
3040
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3041
        table_||$$))$$ INTO STRICT hstore;
3042
    RETURN hstore;
3043
END;
3044
$_$;
3045
3046
3047
--
3048 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3049
--
3050
3051
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3052
    LANGUAGE sql STABLE STRICT
3053
    AS $_$
3054
SELECT COUNT(*) > 0 FROM pg_constraint
3055
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3056
$_$;
3057
3058
3059
--
3060
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3061
--
3062
3063 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3064
gets whether a status flag is set by the presence of a table constraint
3065
';
3066 10184 aaronmk
3067
3068
--
3069 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3070
--
3071
3072
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3073
    LANGUAGE sql STRICT
3074
    AS $_$
3075
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3076
||quote_ident($2)||$$ CHECK (true)$$)
3077
$_$;
3078
3079
3080
--
3081
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3082
--
3083
3084 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3085
stores a status flag by the presence of a table constraint.
3086
idempotent.
3087
';
3088 10182 aaronmk
3089
3090
--
3091 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3092
--
3093
3094
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3095
    LANGUAGE sql STABLE STRICT
3096
    AS $_$
3097
SELECT util.table_flag__get($1, 'nulls_mapped')
3098
$_$;
3099
3100
3101
--
3102
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3103
--
3104
3105 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3106
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3107
';
3108 10185 aaronmk
3109
3110
--
3111 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3112
--
3113
3114
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3115
    LANGUAGE sql STRICT
3116
    AS $_$
3117
SELECT util.table_flag__set($1, 'nulls_mapped')
3118
$_$;
3119
3120
3121
--
3122
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3123
--
3124
3125 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3126
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3127
idempotent.
3128
';
3129 10183 aaronmk
3130
3131
--
3132 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3133 8088 aaronmk
--
3134
3135
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3136
    LANGUAGE plpgsql STRICT
3137
    AS $_$
3138
DECLARE
3139
    row record;
3140
BEGIN
3141 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3142 8088 aaronmk
    LOOP
3143
        IF row.global_name != row.name THEN
3144
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3145
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3146
        END IF;
3147
    END LOOP;
3148
END;
3149
$_$;
3150
3151
3152
--
3153 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3154 8088 aaronmk
--
3155
3156 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3157
idempotent
3158
';
3159 8088 aaronmk
3160
3161
--
3162 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3163
--
3164
3165
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3166
    LANGUAGE sql STRICT
3167
    AS $_$
3168 10595 aaronmk
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3169 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
3170
$_$;
3171
3172
3173
--
3174
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3175
--
3176
3177 12235 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3178
trims table_ to include only columns in the original data.
3179
idempotent.
3180
';
3181 10365 aaronmk
3182
3183
--
3184 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3185 8142 aaronmk
--
3186
3187
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3188
    LANGUAGE plpgsql STRICT
3189
    AS $_$
3190
BEGIN
3191
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3192
END;
3193
$_$;
3194
3195
3196
--
3197 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3198 8142 aaronmk
--
3199
3200 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3201
idempotent
3202
';
3203 8142 aaronmk
3204
3205
--
3206 12357 aaronmk
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3207
--
3208
3209
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3210
    LANGUAGE sql IMMUTABLE
3211
    AS $_$
3212 12361 aaronmk
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3213 12362 aaronmk
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3214 12357 aaronmk
$_$;
3215
3216
3217
--
3218 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3219
--
3220
3221
CREATE FUNCTION try_create(sql text) RETURNS void
3222
    LANGUAGE plpgsql STRICT
3223
    AS $$
3224
BEGIN
3225 10146 aaronmk
    PERFORM util.eval(sql);
3226 8199 aaronmk
EXCEPTION
3227 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3228 8199 aaronmk
    WHEN undefined_column THEN NULL;
3229
    WHEN duplicate_column THEN NULL;
3230
END;
3231
$$;
3232
3233
3234
--
3235
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3236
--
3237
3238 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
3239
idempotent
3240
';
3241 8199 aaronmk
3242
3243
--
3244 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3245
--
3246
3247
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3248
    LANGUAGE sql STRICT
3249
    AS $_$
3250
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3251
$_$;
3252
3253
3254
--
3255
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3256
--
3257
3258 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3259
idempotent
3260
';
3261 8209 aaronmk
3262
3263
--
3264 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3265
--
3266
3267
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3268
    LANGUAGE sql IMMUTABLE
3269
    AS $_$
3270
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3271
$_$;
3272
3273
3274
--
3275 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3276
--
3277
3278 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3279
a type''s NOT NULL qualifier
3280
';
3281 10161 aaronmk
3282
3283
--
3284 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3285
--
3286
3287 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3288
    LANGUAGE plpgsql STABLE
3289 8185 aaronmk
    AS $_$
3290
DECLARE
3291
    type regtype;
3292
BEGIN
3293 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3294
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3295 8185 aaronmk
    RETURN type;
3296
END;
3297
$_$;
3298
3299
3300
--
3301 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3302
--
3303
3304
CREATE AGGREGATE all_same(anyelement) (
3305
    SFUNC = all_same_transform,
3306
    STYPE = anyarray,
3307
    FINALFUNC = all_same_final
3308
);
3309
3310
3311
--
3312
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3313
--
3314
3315 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
3316
includes NULLs in comparison
3317
';
3318 9959 aaronmk
3319
3320
--
3321 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3322 2595 aaronmk
--
3323
3324
CREATE AGGREGATE join_strs(text, text) (
3325 4052 aaronmk
    SFUNC = join_strs_transform,
3326 4010 aaronmk
    STYPE = text
3327 2595 aaronmk
);
3328
3329
3330 8147 aaronmk
--
3331 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3332 8147 aaronmk
--
3333
3334
CREATE OPERATOR -> (
3335
    PROCEDURE = map_get,
3336
    LEFTARG = regclass,
3337
    RIGHTARG = text
3338
);
3339
3340
3341 10308 aaronmk
--
3342
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3343
--
3344
3345
CREATE OPERATOR => (
3346
    PROCEDURE = hstore,
3347 10357 aaronmk
    LEFTARG = text[],
3348 10608 aaronmk
    RIGHTARG = text
3349 10308 aaronmk
);
3350
3351
3352
--
3353 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3354 10308 aaronmk
--
3355
3356 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
3357
usage: array[''key1'', ...]::text[] => ''value''
3358
';
3359 10308 aaronmk
3360
3361 10391 aaronmk
--
3362 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3363
--
3364
3365
CREATE OPERATOR ?*>= (
3366
    PROCEDURE = is_populated_more_often_than,
3367
    LEFTARG = anyelement,
3368
    RIGHTARG = anyelement
3369
);
3370
3371
3372
--
3373 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3374
--
3375
3376
CREATE OPERATOR ?>= (
3377
    PROCEDURE = is_more_complete_than,
3378
    LEFTARG = anyelement,
3379
    RIGHTARG = anyelement
3380
);
3381
3382
3383 11005 aaronmk
--
3384
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3385
--
3386
3387
CREATE OPERATOR ||% (
3388
    PROCEDURE = concat_esc,
3389
    LEFTARG = text,
3390
    RIGHTARG = text
3391
);
3392
3393
3394
--
3395
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3396
--
3397
3398 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
3399
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3400
';
3401 11005 aaronmk
3402
3403 2107 aaronmk
--
3404 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
3405 8140 aaronmk
--
3406
3407
CREATE TABLE map (
3408
    "from" text NOT NULL,
3409 8158 aaronmk
    "to" text,
3410
    filter text,
3411
    notes text
3412 8140 aaronmk
);
3413
3414
3415
--
3416 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3417
--
3418
3419
3420
3421
--
3422 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3423 8140 aaronmk
--
3424
3425
3426
3427
--
3428 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3429 8140 aaronmk
--
3430
3431
ALTER TABLE ONLY map
3432 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3433 8140 aaronmk
3434
3435
--
3436 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3437
--
3438
3439
ALTER TABLE ONLY map
3440
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3441
3442
3443
--
3444 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3445
--
3446
3447
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3448
3449
3450
--
3451 2136 aaronmk
-- PostgreSQL database dump complete
3452
--