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 10305 aaronmk
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
601
--
602
603
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
604
    LANGUAGE sql IMMUTABLE
605
    AS $_$
606
SELECT pg_catalog.array_fill($1, ARRAY[$2])
607
$_$;
608
609
610
--
611 10303 aaronmk
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
612
--
613
614
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
615 10354 aaronmk
    LANGUAGE sql IMMUTABLE
616 10303 aaronmk
    AS $_$
617 10321 aaronmk
SELECT util.array_length($1, 1)
618 10303 aaronmk
$_$;
619
620
621
--
622 10304 aaronmk
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
623
--
624
625
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
626 10354 aaronmk
    LANGUAGE sql IMMUTABLE
627 10304 aaronmk
    AS $_$
628 10354 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
629 10304 aaronmk
$_$;
630
631
632
--
633
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
634
--
635
636 12235 aaronmk
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
637
returns 0 instead of NULL for empty arrays
638
';
639 10304 aaronmk
640
641
--
642 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
643 8104 aaronmk
--
644
645
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
646
    LANGUAGE sql STABLE STRICT
647
    AS $_$
648
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
649
$_$;
650
651
652
--
653 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
654 8105 aaronmk
--
655
656
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
657
    LANGUAGE plpgsql STRICT
658
    AS $_$
659
BEGIN
660
    -- not yet clustered (ARRAY[] compares NULLs literally)
661 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
662 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
663
    END IF;
664
END;
665
$_$;
666
667
668
--
669 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
670 8105 aaronmk
--
671
672 12235 aaronmk
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
673
idempotent
674
';
675 8105 aaronmk
676
677
--
678 10986 aaronmk
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
679
--
680
681
CREATE FUNCTION col__min(col col_ref) RETURNS integer
682
    LANGUAGE sql STABLE
683
    AS $_$
684
SELECT util.eval2val($$
685
SELECT $$||quote_ident($1.name)||$$
686
FROM $$||$1.table_||$$
687
ORDER BY $$||quote_ident($1.name)||$$ ASC
688
LIMIT 1
689
$$, NULL::integer)
690
$_$;
691
692
693
--
694 10136 aaronmk
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
695
--
696
697
CREATE FUNCTION col_comment(col col_ref) RETURNS text
698
    LANGUAGE plpgsql STABLE STRICT
699
    AS $$
700
DECLARE
701
	comment text;
702
BEGIN
703
	SELECT description
704
	FROM pg_attribute
705
	LEFT JOIN pg_description ON objoid = attrelid
706
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
707
	WHERE attrelid = col.table_ AND attname = col.name
708
	INTO STRICT comment
709
	;
710
	RETURN comment;
711
EXCEPTION
712
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
713
END;
714
$$;
715
716
717
--
718 10130 aaronmk
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
719
--
720
721
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
722
    LANGUAGE plpgsql STABLE STRICT
723
    AS $$
724
DECLARE
725
	default_sql text;
726
BEGIN
727
	SELECT adsrc
728
	FROM pg_attribute
729
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
730
	WHERE attrelid = col.table_ AND attname = col.name
731
	INTO STRICT default_sql
732
	;
733
	RETURN default_sql;
734
EXCEPTION
735
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
736
END;
737
$$;
738
739
740
--
741 10134 aaronmk
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
742
--
743
744
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
745
    LANGUAGE sql STABLE
746
    AS $_$
747
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
748
$_$;
749
750
751
--
752
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
753
--
754
755 12235 aaronmk
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
756
ret_type_null: NULL::ret_type
757
';
758 10134 aaronmk
759
760
--
761 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
762 8180 aaronmk
--
763
764
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
765
    LANGUAGE plpgsql STRICT
766
    AS $$
767
BEGIN
768 8183 aaronmk
    PERFORM util.col_type(col);
769 8180 aaronmk
    RETURN true;
770
EXCEPTION
771
    WHEN undefined_column THEN RETURN false;
772
END;
773
$$;
774
775
776
--
777 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
778 8084 aaronmk
--
779
780
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
781 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
782 8084 aaronmk
    AS $$
783
DECLARE
784 8183 aaronmk
    prefix text := util.name(type)||'.';
785 8084 aaronmk
BEGIN
786
    RETURN QUERY
787 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
788
        FROM util.col_names(type) f (name_);
789 8084 aaronmk
END;
790
$$;
791
792
793
--
794 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
795 8151 aaronmk
--
796
797
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
798
    LANGUAGE sql STABLE STRICT
799
    AS $_$
800
SELECT attname::text
801
FROM pg_attribute
802 10158 aaronmk
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
803 8151 aaronmk
ORDER BY attnum
804
$_$;
805
806
807
--
808 11667 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
809
--
810
811
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
812
    LANGUAGE plpgsql STABLE STRICT
813
    AS $_$
814
BEGIN
815
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
816
END;
817
$_$;
818
819
820
--
821 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
822 8106 aaronmk
--
823
824
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
825 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
826
    AS $$
827
DECLARE
828
    type regtype;
829
BEGIN
830
    SELECT atttypid FROM pg_attribute
831
    WHERE attrelid = col.table_ AND attname = col.name
832
    INTO STRICT type
833
    ;
834
    RETURN type;
835
EXCEPTION
836 8171 aaronmk
    WHEN no_data_found THEN
837 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
838
            concat('undefined column: ', col.name);
839 8169 aaronmk
END;
840
$$;
841 8106 aaronmk
842
843
--
844 11005 aaronmk
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
845
--
846
847
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
848
    LANGUAGE sql IMMUTABLE
849
    AS $_$
850
SELECT util.esc_name__append($2, $1)
851
$_$;
852
853
854
--
855 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
856 8095 aaronmk
--
857
858
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
859 10388 aaronmk
    LANGUAGE sql IMMUTABLE
860 8095 aaronmk
    AS $_$
861
SELECT position($1 in $2) > 0 /*1-based offset*/
862
$_$;
863
864
865
--
866 12288 aaronmk
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
867
--
868
869
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
870
    LANGUAGE sql
871
    AS $_$
872
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
873
$_$;
874
875
876
--
877 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
878 8094 aaronmk
--
879
880
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
881
    LANGUAGE plpgsql STRICT
882
    AS $$
883
BEGIN
884 10146 aaronmk
    PERFORM util.eval(sql);
885 8094 aaronmk
EXCEPTION
886 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
887 10181 aaronmk
    WHEN duplicate_object THEN NULL; -- e.g. constraint
888 8103 aaronmk
    WHEN duplicate_column THEN NULL;
889 10244 aaronmk
    WHEN invalid_table_definition THEN
890
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
891
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
892
        END IF;
893 8094 aaronmk
END;
894
$$;
895
896
897
--
898 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
899 8094 aaronmk
--
900
901 12235 aaronmk
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
902
idempotent
903
';
904 8094 aaronmk
905
906
--
907 12250 aaronmk
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
908
--
909
910
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
911
    LANGUAGE sql IMMUTABLE
912
    AS $_$
913
/* newline before so the query starts at the beginning of the line.
914
newline after to visually separate queries from one another. */
915
SELECT util.raise_notice($$
916
$$||$1||$$
917
$$)
918
$_$;
919
920
921
--
922 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
923
--
924
925
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
926
    LANGUAGE sql STABLE STRICT
927
    AS $_$
928
SELECT util.eval2set($$
929
SELECT col
930
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
931
LEFT JOIN $$||$2||$$ ON "to" = col
932
WHERE "from" IS NULL
933
$$, NULL::text)
934
$_$;
935
936
937
--
938
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
939
--
940
941 12235 aaronmk
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
942
gets table_''s derived columns (all the columns not in the names table)
943
';
944 10364 aaronmk
945
946
--
947 12298 aaronmk
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
948 12044 aaronmk
--
949
950 12298 aaronmk
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
951 12044 aaronmk
    LANGUAGE sql STABLE
952
    AS $_$
953 12300 aaronmk
SELECT * FROM util.diff($1::text, $2::text, $3,
954
	util.has_single_row($1) AND util.has_single_row($2))
955 12298 aaronmk
$_$;
956
957
958
--
959
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
960
--
961
962
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
963
col_type_null (*required*): NULL::shared_base_type
964
usage:
965
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
966
';
967
968
969
--
970
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
971
--
972
973
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
974
    LANGUAGE sql STABLE
975
    AS $_$
976 12044 aaronmk
SELECT * FROM
977 12184 aaronmk
util.eval2col_pair($$
978 12284 aaronmk
/* need to explicitly cast each side to the return type because this does not
979
happen automatically even when an implicit cast is available */
980
SELECT left_::$$||pg_typeof($3)||$$, right_::$$||pg_typeof($3)||$$
981 12299 aaronmk
FROM $$||$1||$$ left_
982
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
983 12308 aaronmk
$$||util._if($4, ''::text, $$ON left_ = right_
984
$$)||
985
$$WHERE left_ IS DISTINCT FROM right_
986 12044 aaronmk
ORDER BY left_, right_
987 12308 aaronmk
$$, $3)
988 12044 aaronmk
$_$;
989
990
991
--
992 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: -
993 12280 aaronmk
--
994
995 12298 aaronmk
COMMENT ON FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
996 12280 aaronmk
col_type_null (*required*): NULL::col_type
997 12299 aaronmk
single_row: whether the tables consist of a single row, which should be
998
	displayed side-by-side
999 12282 aaronmk
1000
to run EXPLAIN on the FULL JOIN query:
1001
# run this function
1002
# look for a NOTICE containing the expanded query that it ran
1003
# run EXPLAIN on this expanded query
1004 12280 aaronmk
';
1005
1006
1007
--
1008 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1009
--
1010
1011
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1012
    LANGUAGE sql STRICT
1013
    AS $_$
1014
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1015
$_$;
1016
1017
1018
--
1019
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1020
--
1021
1022 12235 aaronmk
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1023
idempotent
1024
';
1025 8200 aaronmk
1026
1027
--
1028 12292 aaronmk
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1029 10362 aaronmk
--
1030
1031 12292 aaronmk
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1032 10362 aaronmk
    LANGUAGE sql STRICT
1033
    AS $_$
1034
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1035 12292 aaronmk
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1036 10362 aaronmk
$_$;
1037
1038
1039
--
1040 12292 aaronmk
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1041 10362 aaronmk
--
1042
1043 12292 aaronmk
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1044 12235 aaronmk
idempotent
1045
';
1046 10362 aaronmk
1047
1048
--
1049 12331 aaronmk
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1050
--
1051
1052
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1053
    LANGUAGE sql
1054
    AS $_$
1055 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1056
included in the debug SQL */
1057
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1058 12331 aaronmk
$_$;
1059
1060
1061
--
1062 12343 aaronmk
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1063
--
1064
1065 12347 aaronmk
CREATE FUNCTION drop_relation(type text, relation text, force boolean DEFAULT false) RETURNS void
1066 12343 aaronmk
    LANGUAGE sql
1067
    AS $_$
1068 12347 aaronmk
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1069 12343 aaronmk
||util._if($3, $$ CASCADE$$, ''::text))
1070
$_$;
1071
1072
1073
--
1074 12347 aaronmk
-- Name: FUNCTION drop_relation(type text, relation text, force boolean); Type: COMMENT; Schema: util; Owner: -
1075 12343 aaronmk
--
1076
1077 12347 aaronmk
COMMENT ON FUNCTION drop_relation(type text, relation text, force boolean) IS '
1078 12343 aaronmk
idempotent
1079
';
1080
1081
1082
--
1083 12292 aaronmk
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1084 10150 aaronmk
--
1085
1086 12292 aaronmk
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1087 10150 aaronmk
    LANGUAGE sql STRICT
1088
    AS $_$
1089 12347 aaronmk
SELECT util.drop_relation('TABLE', $1, $2)
1090 10150 aaronmk
$_$;
1091
1092
1093
--
1094 12292 aaronmk
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1095 10150 aaronmk
--
1096
1097 12292 aaronmk
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1098 12235 aaronmk
idempotent
1099
';
1100 10150 aaronmk
1101
1102
--
1103 12292 aaronmk
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1104 12229 aaronmk
--
1105
1106 12292 aaronmk
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1107 12229 aaronmk
    LANGUAGE sql STRICT
1108
    AS $_$
1109 12347 aaronmk
SELECT util.drop_relation('VIEW', $1, $2)
1110 12229 aaronmk
$_$;
1111
1112
1113
--
1114 12292 aaronmk
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1115 12229 aaronmk
--
1116
1117 12292 aaronmk
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1118 12235 aaronmk
idempotent
1119
';
1120 12229 aaronmk
1121
1122
--
1123 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1124
--
1125
1126
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1127
    LANGUAGE sql IMMUTABLE
1128
    AS $_$
1129
SELECT util.array_fill($1, 0)
1130
$_$;
1131
1132
1133
--
1134
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1135
--
1136
1137 12235 aaronmk
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1138
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1139
';
1140 10322 aaronmk
1141
1142
--
1143 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1144 8086 aaronmk
--
1145
1146
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1147 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1148 8086 aaronmk
    AS $_$
1149 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1150 8086 aaronmk
$_$;
1151
1152
1153
--
1154 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1155
--
1156
1157
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1158
    LANGUAGE sql IMMUTABLE
1159
    AS $_$
1160
SELECT regexp_replace($2, '("?)$', $1||'\1')
1161
$_$;
1162
1163
1164
--
1165 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1166
--
1167
1168
CREATE FUNCTION eval(sql text) RETURNS void
1169
    LANGUAGE plpgsql STRICT
1170
    AS $$
1171
BEGIN
1172 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1173
	EXECUTE sql;
1174 9824 aaronmk
END;
1175
$$;
1176
1177
1178
--
1179 12181 aaronmk
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1180
--
1181
1182
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1183
    LANGUAGE plpgsql
1184
    AS $$
1185
BEGIN
1186 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1187 12181 aaronmk
	RETURN QUERY EXECUTE sql;
1188
END;
1189
$$;
1190
1191
1192
--
1193
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1194
--
1195
1196 12235 aaronmk
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1197
col_type_null (*required*): NULL::col_type
1198
';
1199 12181 aaronmk
1200
1201
--
1202 12301 aaronmk
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1203
--
1204
1205
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1206
    LANGUAGE plpgsql
1207
    AS $$
1208
BEGIN
1209
	PERFORM util.debug_print_sql(sql);
1210
	RETURN QUERY EXECUTE sql;
1211
END;
1212
$$;
1213
1214
1215
--
1216 10363 aaronmk
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1217
--
1218
1219
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1220
    LANGUAGE plpgsql
1221
    AS $$
1222
BEGIN
1223 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1224 10363 aaronmk
	RETURN QUERY EXECUTE sql;
1225
END;
1226
$$;
1227
1228
1229
--
1230
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1231
--
1232
1233 12235 aaronmk
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1234
ret_type_null: NULL::ret_type
1235
';
1236 10363 aaronmk
1237
1238
--
1239 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1240 10128 aaronmk
--
1241
1242 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1243 10128 aaronmk
    LANGUAGE plpgsql
1244
    AS $$
1245
DECLARE
1246
	ret_val ret_type_null%TYPE;
1247
BEGIN
1248 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1249 10128 aaronmk
	EXECUTE sql INTO STRICT ret_val;
1250
	RETURN ret_val;
1251
END;
1252
$$;
1253
1254
1255
--
1256 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1257 10128 aaronmk
--
1258
1259 12235 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1260
ret_type_null: NULL::ret_type
1261
';
1262 10128 aaronmk
1263
1264
--
1265 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1266
--
1267
1268
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1269
    LANGUAGE sql
1270
    AS $_$
1271 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1272 10131 aaronmk
$_$;
1273
1274
1275
--
1276
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1277
--
1278
1279 12235 aaronmk
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1280
ret_type_null: NULL::ret_type
1281
';
1282 10131 aaronmk
1283
1284
--
1285 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1286
--
1287
1288
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1289
    LANGUAGE sql
1290
    AS $_$
1291
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1292
$_$;
1293
1294
1295
--
1296
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1297
--
1298
1299 12235 aaronmk
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1300
sql: can be NULL, which will be passed through
1301
ret_type_null: NULL::ret_type
1302
';
1303 10133 aaronmk
1304
1305
--
1306 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1307 8182 aaronmk
--
1308
1309
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1310
    LANGUAGE sql STABLE STRICT
1311
    AS $_$
1312
SELECT col_name
1313
FROM unnest($2) s (col_name)
1314 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1315 8182 aaronmk
$_$;
1316
1317
1318
--
1319 11830 aaronmk
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1320
--
1321
1322
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1323
    LANGUAGE sql
1324
    AS $_$
1325
SELECT util.eval2set($$EXPLAIN $$||$1)
1326
$_$;
1327
1328
1329
--
1330 11833 aaronmk
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1331
--
1332
1333
CREATE FUNCTION explain2notice(sql text) RETURNS void
1334
    LANGUAGE plpgsql
1335
    AS $_$
1336
BEGIN
1337
	RAISE NOTICE '%', $$EXPLAIN:
1338
$$||util.explain2str(sql);
1339
END;
1340
$_$;
1341
1342
1343
--
1344 11832 aaronmk
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1345
--
1346
1347
CREATE FUNCTION explain2str(sql text) RETURNS text
1348
    LANGUAGE sql
1349
    AS $_$
1350
SELECT util.join_strs(explain, $$
1351
$$) FROM util.explain($1)
1352
$_$;
1353
1354
1355 11835 aaronmk
SET default_tablespace = '';
1356
1357
SET default_with_oids = false;
1358
1359 11832 aaronmk
--
1360 11835 aaronmk
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace:
1361 11831 aaronmk
--
1362
1363 11835 aaronmk
CREATE TABLE explain (
1364
    line text NOT NULL
1365
);
1366
1367
1368
--
1369
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1370
--
1371
1372
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1373 11831 aaronmk
    LANGUAGE sql
1374
    AS $_$
1375 11835 aaronmk
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1376
$$||quote_nullable($1)||$$
1377 11831 aaronmk
)$$)
1378
$_$;
1379
1380
1381
--
1382 11836 aaronmk
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1383
--
1384
1385 12235 aaronmk
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1386
usage:
1387 11836 aaronmk
PERFORM util.explain2table($$
1388
query
1389 12235 aaronmk
$$);
1390
';
1391 11836 aaronmk
1392
1393
--
1394 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1395
--
1396
1397
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1398 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1399 10323 aaronmk
    AS $_$
1400 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1401
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1402
) END
1403 10323 aaronmk
$_$;
1404
1405
1406
--
1407
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1408
--
1409
1410 12235 aaronmk
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1411
ensures that an array will always have proper non-NULL dimensions
1412
';
1413 10323 aaronmk
1414
1415
--
1416 11695 aaronmk
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1417
--
1418
1419
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1420
    LANGUAGE plpgsql
1421
    AS $_$
1422
DECLARE
1423
	PG_EXCEPTION_DETAIL text;
1424
	recreate_users_cmd text = util.save_drop_views(users);
1425
BEGIN
1426
	PERFORM util.eval(cmd);
1427
	PERFORM util.eval(recreate_users_cmd);
1428
EXCEPTION
1429
WHEN dependent_objects_still_exist THEN
1430
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1431
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1432
	users = array(SELECT * FROM util.regexp_matches_group(
1433
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1434
	IF util.is_empty(users) THEN RAISE; END IF;
1435
	PERFORM util.force_recreate(cmd, users);
1436
END;
1437
$_$;
1438
1439
1440
--
1441
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1442
--
1443
1444 12235 aaronmk
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1445
idempotent
1446 11695 aaronmk
1447 12235 aaronmk
users: not necessary to provide this because it will be autopopulated
1448
';
1449 11695 aaronmk
1450
1451
--
1452 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1453
--
1454
1455
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1456
    LANGUAGE plpgsql STRICT
1457
    AS $_$
1458
DECLARE
1459
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1460
$$||query;
1461
BEGIN
1462
	EXECUTE mk_view;
1463
EXCEPTION
1464
WHEN invalid_table_definition THEN
1465 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1466
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1467
	THEN
1468 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1469
		EXECUTE mk_view;
1470
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1471
	END IF;
1472
END;
1473
$_$;
1474
1475
1476
--
1477
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1478
--
1479
1480 12235 aaronmk
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1481
idempotent
1482
';
1483 8321 aaronmk
1484
1485
--
1486 11655 aaronmk
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1487
--
1488
1489
CREATE FUNCTION grants_users() RETURNS SETOF text
1490
    LANGUAGE sql IMMUTABLE
1491
    AS $$
1492
VALUES ('bien_read'), ('public_')
1493
$$;
1494
1495
1496
--
1497 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1498 8085 aaronmk
--
1499
1500
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1501 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1502 8085 aaronmk
    AS $_$
1503
SELECT substring($2 for length($1)) = $1
1504
$_$;
1505
1506
1507
--
1508 12296 aaronmk
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1509
--
1510
1511
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1512
    LANGUAGE sql STABLE
1513
    AS $_$
1514
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1515
$_$;
1516
1517
1518
--
1519 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1520
--
1521
1522
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1523
    LANGUAGE sql IMMUTABLE
1524
    AS $_$
1525 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1526 10307 aaronmk
$_$;
1527
1528
1529
--
1530
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1531
--
1532
1533 12235 aaronmk
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1534
avoids repeating the same value for each key
1535
';
1536 10307 aaronmk
1537
1538
--
1539 12218 aaronmk
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1540
--
1541
1542
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1543
    LANGUAGE sql IMMUTABLE
1544
    AS $_$
1545 12222 aaronmk
SELECT COALESCE($1, $2)
1546 12218 aaronmk
$_$;
1547
1548
1549
--
1550
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1551
--
1552
1553 12235 aaronmk
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1554
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1555
';
1556 12218 aaronmk
1557
1558
--
1559 12285 aaronmk
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1560
--
1561
1562
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1563
    LANGUAGE sql
1564
    AS $_$
1565
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1566
$_$;
1567
1568
1569
--
1570 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1571
--
1572
1573
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1574
    LANGUAGE sql STABLE STRICT
1575
    AS $_$
1576
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1577
$_$;
1578
1579
1580
--
1581 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1582
--
1583
1584
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1585
    LANGUAGE sql IMMUTABLE
1586
    AS $_$
1587
SELECT util.array_length($1) = 0
1588
$_$;
1589
1590
1591
--
1592 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1593
--
1594
1595
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1596
    LANGUAGE sql IMMUTABLE
1597
    AS $_$
1598
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1599
$_$;
1600
1601
1602
--
1603 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1604
--
1605
1606
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1607
    LANGUAGE sql IMMUTABLE
1608
    AS $_$
1609
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1610
$_$;
1611
1612
1613
--
1614 12330 aaronmk
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1615
--
1616
1617
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1618 12332 aaronmk
    LANGUAGE sql STABLE
1619 12330 aaronmk
    AS $_$
1620
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1621
$_$;
1622
1623
1624
--
1625 12329 aaronmk
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1626
--
1627
1628
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1629 12332 aaronmk
    LANGUAGE sql STABLE
1630 12329 aaronmk
    AS $_$
1631
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1632
$_$;
1633
1634
1635
--
1636 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1637 4009 aaronmk
--
1638
1639 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1640 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1641 4009 aaronmk
    AS $_$
1642 4054 aaronmk
SELECT $1 || $3 || $2
1643 2595 aaronmk
$_$;
1644
1645
1646
--
1647 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1648 10985 aaronmk
--
1649
1650 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1651 10985 aaronmk
    LANGUAGE sql IMMUTABLE
1652
    AS $_$
1653 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1654 10985 aaronmk
$_$;
1655
1656
1657
--
1658 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1659
--
1660
1661
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1662
    LANGUAGE sql IMMUTABLE
1663
    AS $_$
1664
SELECT ltrim($1, $$
1665
$$)
1666
$_$;
1667
1668
1669
--
1670 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1671
--
1672
1673
CREATE FUNCTION map_filter_insert() RETURNS trigger
1674
    LANGUAGE plpgsql
1675
    AS $$
1676
BEGIN
1677
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1678
	RETURN new;
1679
END;
1680
$$;
1681
1682
1683
--
1684 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1685 8146 aaronmk
--
1686
1687
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1688
    LANGUAGE plpgsql STABLE STRICT
1689
    AS $_$
1690
DECLARE
1691
    value text;
1692
BEGIN
1693
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1694 8149 aaronmk
        INTO value USING key;
1695 8146 aaronmk
    RETURN value;
1696
END;
1697
$_$;
1698
1699
1700
--
1701 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1702 10325 aaronmk
--
1703
1704 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1705 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1706 10325 aaronmk
    AS $_$
1707 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1708 10325 aaronmk
$_$;
1709
1710
1711
--
1712 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1713
--
1714
1715 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
1716
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
1717 10359 aaronmk
1718
[1] inlining of function calls, which is different from constant folding
1719
[2] _map()''s profiling query
1720
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1721
and map_nulls()''s profiling query
1722
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1723 10375 aaronmk
both take ~920 ms.
1724 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.
1725
';
1726 10359 aaronmk
1727
1728
--
1729 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1730 8150 aaronmk
--
1731
1732
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1733
    LANGUAGE plpgsql STABLE STRICT
1734
    AS $_$
1735
BEGIN
1736
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1737
END;
1738
$_$;
1739
1740
1741
--
1742 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1743
--
1744
1745 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1746 12228 aaronmk
    LANGUAGE sql
1747
    AS $_$
1748 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1749 12321 aaronmk
$$||util.ltrim_nl($2));
1750
-- make sure the created table has the correct estimated row count
1751
SELECT util.analyze_($1);
1752 12228 aaronmk
$_$;
1753
1754
1755
--
1756 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1757 12228 aaronmk
--
1758
1759 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1760 12235 aaronmk
idempotent
1761
';
1762 12228 aaronmk
1763
1764
--
1765 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1766
--
1767
1768 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1769 12234 aaronmk
    LANGUAGE sql
1770
    AS $_$
1771
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1772
$_$;
1773
1774
1775
--
1776 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1777 12234 aaronmk
--
1778
1779 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1780 12235 aaronmk
idempotent
1781
';
1782 12234 aaronmk
1783
1784
--
1785 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1786
--
1787
1788
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1789
    LANGUAGE sql STRICT
1790
    AS $_$
1791 10135 aaronmk
SELECT util.create_if_not_exists($$
1792
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1793 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1794 10135 aaronmk
||quote_literal($2)||$$;
1795 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1796
constant
1797
';
1798 10135 aaronmk
$$)
1799 8190 aaronmk
$_$;
1800
1801
1802
--
1803
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1804
--
1805
1806 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1807
idempotent
1808
';
1809 8190 aaronmk
1810
1811
--
1812 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1813 8187 aaronmk
--
1814
1815 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1816 8187 aaronmk
    LANGUAGE plpgsql STRICT
1817
    AS $_$
1818
DECLARE
1819
    type regtype = util.typeof(expr, col.table_::text::regtype);
1820
    col_name_sql text = quote_ident(col.name);
1821
BEGIN
1822 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1823
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1824 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1825
$$||expr||$$;
1826
$$);
1827
END;
1828
$_$;
1829
1830
1831
--
1832 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1833 8188 aaronmk
--
1834
1835 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1836
idempotent
1837
';
1838 8188 aaronmk
1839
1840
--
1841 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1842 8139 aaronmk
--
1843
1844
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1845 8141 aaronmk
    LANGUAGE sql STRICT
1846 8139 aaronmk
    AS $_$
1847 8183 aaronmk
SELECT util.create_if_not_exists($$
1848 8141 aaronmk
CREATE TABLE $$||$1||$$
1849 8139 aaronmk
(
1850 8183 aaronmk
    LIKE util.map INCLUDING ALL
1851 10110 aaronmk
);
1852
1853
CREATE TRIGGER map_filter_insert
1854
  BEFORE INSERT
1855
  ON $$||$1||$$
1856
  FOR EACH ROW
1857
  EXECUTE PROCEDURE util.map_filter_insert();
1858 8141 aaronmk
$$)
1859 8139 aaronmk
$_$;
1860
1861
1862
--
1863 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1864
--
1865
1866
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1867
    LANGUAGE sql IMMUTABLE
1868
    AS $_$
1869
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1870
$_$;
1871
1872
1873
--
1874 12272 aaronmk
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1875
--
1876
1877
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1878
    LANGUAGE sql IMMUTABLE
1879
    AS $_$
1880
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1881
$_$;
1882
1883
1884
--
1885
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1886
--
1887
1888
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1889
usage:
1890
for *1* schema arg:
1891
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1892
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1893
';
1894
1895
1896
--
1897 12270 aaronmk
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1898
--
1899
1900
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1901
    LANGUAGE sql IMMUTABLE
1902
    AS $_$
1903
SELECT $$SET LOCAL search_path TO $$||$1
1904
$_$;
1905
1906
1907
--
1908 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1909
--
1910
1911
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1912
    LANGUAGE sql STRICT
1913
    AS $_$
1914 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1915 10113 aaronmk
$_$;
1916
1917
1918
--
1919
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1920
--
1921
1922 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1923
idempotent
1924
';
1925 10113 aaronmk
1926
1927
--
1928 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1929
--
1930
1931
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1932
    LANGUAGE plpgsql STRICT
1933
    AS $_$
1934
DECLARE
1935
	view_qual_name text = util.qual_name(view_);
1936
BEGIN
1937
	EXECUTE $$
1938
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1939
  RETURNS SETOF $$||view_||$$ AS
1940
$BODY1$
1941
SELECT * FROM $$||view_qual_name||$$
1942
ORDER BY sort_col
1943
LIMIT $1 OFFSET $2
1944
$BODY1$
1945
  LANGUAGE sql STABLE
1946
  COST 100
1947
  ROWS 1000
1948
$$;
1949
1950
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1951
END;
1952
$_$;
1953
1954
1955
--
1956 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1957
--
1958
1959
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1960
    LANGUAGE plpgsql STRICT
1961
    AS $_$
1962 10990 aaronmk
DECLARE
1963
	view_qual_name text = util.qual_name(view_);
1964
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1965 8325 aaronmk
BEGIN
1966
	EXECUTE $$
1967 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1968
  RETURNS integer AS
1969
$BODY1$
1970
SELECT $$||quote_ident(row_num_col)||$$
1971
FROM $$||view_qual_name||$$
1972
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1973
LIMIT 1
1974
$BODY1$
1975
  LANGUAGE sql STABLE
1976
  COST 100;
1977
$$;
1978
1979
	EXECUTE $$
1980 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1981
  RETURNS SETOF $$||view_||$$ AS
1982
$BODY1$
1983 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
1984
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1985
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1986
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1987 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
1988 8325 aaronmk
$BODY1$
1989
  LANGUAGE sql STABLE
1990
  COST 100
1991
  ROWS 1000
1992
$$;
1993 11010 aaronmk
1994
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1995
END;
1996
$_$;
1997
1998
1999
--
2000
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2001
--
2002
2003
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2004
    LANGUAGE plpgsql STRICT
2005
    AS $_$
2006
DECLARE
2007
	view_qual_name text = util.qual_name(view_);
2008
BEGIN
2009 8326 aaronmk
	EXECUTE $$
2010
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2011
  RETURNS SETOF $$||view_||$$
2012
  SET enable_sort TO 'off'
2013
  AS
2014
$BODY1$
2015 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
2016 8326 aaronmk
$BODY1$
2017
  LANGUAGE sql STABLE
2018
  COST 100
2019
  ROWS 1000
2020
;
2021
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2022
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2023
If you want to run EXPLAIN and get expanded output, use the regular subset
2024
function instead. (When a config param is set on a function, EXPLAIN produces
2025
just a function scan.)
2026
';
2027
$$;
2028 8325 aaronmk
END;
2029
$_$;
2030
2031
2032
--
2033 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2034
--
2035
2036 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2037
creates subset function which turns off enable_sort
2038
';
2039 11010 aaronmk
2040
2041
--
2042 12271 aaronmk
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2043
--
2044
2045
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2046
    LANGUAGE sql IMMUTABLE
2047
    AS $_$
2048
SELECT util.mk_set_search_path(util.schema_esc($1))
2049
$_$;
2050
2051
2052
--
2053 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2054
--
2055
2056
CREATE FUNCTION name(table_ regclass) RETURNS text
2057
    LANGUAGE sql STABLE
2058
    AS $_$
2059
SELECT relname::text FROM pg_class WHERE oid = $1
2060
$_$;
2061
2062
2063
--
2064 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2065 8083 aaronmk
--
2066
2067
CREATE FUNCTION name(type regtype) RETURNS text
2068 8097 aaronmk
    LANGUAGE sql STABLE STRICT
2069 8083 aaronmk
    AS $_$
2070
SELECT typname::text FROM pg_type WHERE oid = $1
2071
$_$;
2072
2073
2074
--
2075 12360 aaronmk
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2076 12355 aaronmk
--
2077
2078 12360 aaronmk
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2079 12355 aaronmk
    LANGUAGE sql IMMUTABLE
2080
    AS $_$
2081 12360 aaronmk
SELECT octet_length($1) >= util.namedatalen() - $2
2082 12355 aaronmk
$_$;
2083
2084
2085
--
2086 12354 aaronmk
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2087
--
2088
2089
CREATE FUNCTION namedatalen() RETURNS integer
2090
    LANGUAGE sql IMMUTABLE
2091
    AS $$
2092
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2093
$$;
2094
2095
2096
--
2097 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2098
--
2099
2100
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2101
    LANGUAGE sql IMMUTABLE
2102
    AS $_$
2103 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2104 9958 aaronmk
$_$;
2105
2106
2107
--
2108 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2109
--
2110
2111
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2112 9957 aaronmk
    LANGUAGE sql IMMUTABLE
2113 9956 aaronmk
    AS $_$
2114
SELECT $1 IS NOT NULL
2115
$_$;
2116
2117
2118
--
2119 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2120
--
2121
2122
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2123
    LANGUAGE sql IMMUTABLE
2124
    AS $_$
2125
SELECT util.hstore($1, NULL) || '*=>*'
2126
$_$;
2127
2128
2129
--
2130
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2131
--
2132
2133 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2134
for use with _map()
2135
';
2136 10373 aaronmk
2137
2138
--
2139 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2140 10984 aaronmk
--
2141
2142 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2143 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2144
    AS $_$
2145 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2146 10984 aaronmk
$_$;
2147
2148
2149
--
2150 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2151
--
2152
2153
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2154
    LANGUAGE sql IMMUTABLE
2155
    AS $_$
2156
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2157
$_$;
2158
2159
2160
--
2161 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2162
--
2163
2164
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2165 12267 aaronmk
    LANGUAGE sql STABLE STRICT
2166
    SET search_path TO pg_temp
2167 10988 aaronmk
    AS $_$
2168 12267 aaronmk
SELECT $1::text
2169 10988 aaronmk
$_$;
2170
2171
2172
--
2173 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2174
--
2175
2176
CREATE FUNCTION qual_name(type regtype) RETURNS text
2177
    LANGUAGE sql STABLE STRICT
2178
    SET search_path TO pg_temp
2179
    AS $_$
2180
SELECT $1::text
2181
$_$;
2182
2183
2184
--
2185
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2186
--
2187
2188
COMMENT ON FUNCTION qual_name(type regtype) IS '
2189
a type''s schema-qualified name
2190
';
2191
2192
2193
--
2194 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2195
--
2196
2197
CREATE FUNCTION qual_name(type unknown) RETURNS text
2198
    LANGUAGE sql STABLE STRICT
2199
    AS $_$
2200
SELECT util.qual_name($1::text::regtype)
2201
$_$;
2202
2203
2204
--
2205 12311 aaronmk
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2206
--
2207
2208
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2209
    LANGUAGE sql IMMUTABLE STRICT
2210
    AS $_$
2211
SELECT util.raise_notice('ERROR:  '||$1)
2212
$_$;
2213
2214
2215
--
2216 12249 aaronmk
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2217
--
2218
2219
CREATE FUNCTION raise_notice(msg text) RETURNS void
2220
    LANGUAGE plpgsql IMMUTABLE STRICT
2221
    AS $$
2222
BEGIN
2223
	RAISE NOTICE '%', msg;
2224
END;
2225
$$;
2226
2227
2228
--
2229 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2230
--
2231
2232
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2233
    LANGUAGE plpgsql IMMUTABLE STRICT
2234
    AS $$
2235
BEGIN
2236
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2237
END;
2238
$$;
2239
2240
2241
--
2242 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2243
--
2244
2245
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2246
    LANGUAGE sql IMMUTABLE
2247
    AS $_$
2248
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2249
$_$;
2250
2251
2252
--
2253 12333 aaronmk
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2254
--
2255
2256
CREATE FUNCTION regexp_quote(str text) RETURNS text
2257
    LANGUAGE sql IMMUTABLE
2258
    AS $_$
2259
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2260
$_$;
2261
2262
2263
--
2264 12344 aaronmk
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2265
--
2266
2267
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2268
    LANGUAGE sql STABLE
2269
    AS $_$
2270
SELECT util.relation_type(util.relation_type_char($1))
2271
$_$;
2272
2273
2274
--
2275 12340 aaronmk
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2276 12339 aaronmk
--
2277
2278 12340 aaronmk
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2279 12339 aaronmk
    LANGUAGE sql IMMUTABLE
2280
    AS $_$
2281
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2282
$_$;
2283
2284
2285
--
2286 12341 aaronmk
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2287
--
2288
2289
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2290
    LANGUAGE sql STABLE
2291
    AS $_$
2292
SELECT relkind FROM pg_class WHERE oid = $1
2293
$_$;
2294
2295
2296
--
2297 12293 aaronmk
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2298
--
2299
2300
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2301
    LANGUAGE sql
2302
    AS $_$
2303
/* can't have in_table/out_table inherit from *each other*, because inheritance
2304
also causes the rows of the parent table to be included in the child table.
2305
instead, they need to inherit from a common, empty table. */
2306
SELECT util.drop_table($4, force := true);
2307
SELECT util.copy_struct($2, $4);
2308
SELECT util.inherit($2, $4);
2309
SELECT util.inherit($3, $4);
2310
2311
SELECT util.rematerialize_query($1, $$
2312
SELECT * FROM util.diff(
2313 12297 aaronmk
  $$||quote_nullable($2)||$$::regclass
2314
, $$||quote_nullable($3)||$$::regclass
2315 12293 aaronmk
, NULL::$$||$4||$$)
2316
$$);
2317 12303 aaronmk
2318
/* the table unfortunately cannot be *materialized* in human-readable form,
2319
because this would create column name collisions between the two sides */
2320
SELECT util.set_comment($1, '
2321
to view this table in human-readable form (with each side''s tuple column
2322
expanded to its component fields):
2323
SELECT (left_).*, (right_).* FROM '||$1||';
2324
');
2325 12293 aaronmk
$_$;
2326
2327
2328
--
2329
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2330
--
2331
2332
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2333
type_table (*required*): table to create as the shared base type
2334
';
2335
2336
2337
--
2338 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2339
--
2340
2341
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2342
    LANGUAGE sql
2343
    AS $_$
2344
SELECT util.drop_table($1);
2345
SELECT util.materialize_query($1, $2);
2346
$_$;
2347
2348
2349
--
2350
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2351
--
2352
2353
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2354
idempotent, but repeats action each time
2355
';
2356
2357
2358
--
2359 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2360
--
2361
2362 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2363 12247 aaronmk
    LANGUAGE sql
2364
    AS $_$
2365
SELECT util.drop_table($1);
2366
SELECT util.materialize_view($1, $2);
2367
$_$;
2368
2369
2370
--
2371 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2372 12247 aaronmk
--
2373
2374 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2375 12247 aaronmk
idempotent, but repeats action each time
2376
';
2377
2378
2379
--
2380 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2381 8137 aaronmk
--
2382
2383 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2384 8137 aaronmk
    LANGUAGE sql STRICT
2385
    AS $_$
2386 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2387 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2388 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
2389
SELECT NULL::void; -- don't fold away functions called in previous query
2390 8137 aaronmk
$_$;
2391
2392
2393
--
2394 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2395 8137 aaronmk
--
2396
2397 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2398
idempotent
2399
';
2400 8137 aaronmk
2401
2402
--
2403 12349 aaronmk
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2404
--
2405
2406
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2407
    LANGUAGE sql
2408
    AS $_$
2409 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2410
included in the debug SQL */
2411
SELECT util.rename_relation(util.qual_name($1), $2)
2412 12349 aaronmk
$_$;
2413
2414
2415
--
2416
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2417
--
2418
2419
CREATE FUNCTION rename_relation(from_ text, to_ text) RETURNS void
2420
    LANGUAGE sql
2421
    AS $_$
2422
/* 'ALTER TABLE can be used with views too'
2423
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2424
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$||$2)
2425
$_$;
2426
2427
2428
--
2429
-- Name: FUNCTION rename_relation(from_ text, to_ text); Type: COMMENT; Schema: util; Owner: -
2430
--
2431
2432
COMMENT ON FUNCTION rename_relation(from_ text, to_ text) IS '
2433
idempotent
2434
';
2435
2436
2437
--
2438 12358 aaronmk
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2439 12350 aaronmk
--
2440
2441 12358 aaronmk
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2442 12350 aaronmk
    LANGUAGE sql IMMUTABLE
2443
    AS $_$
2444 12358 aaronmk
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2445 12350 aaronmk
$_$;
2446
2447
2448
--
2449 12358 aaronmk
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2450
--
2451
2452
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2453
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
2454
';
2455
2456
2457
--
2458 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2459
--
2460
2461
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2462
    LANGUAGE sql STRICT
2463
    AS $_$
2464 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2465
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2466 10297 aaronmk
SELECT util.set_col_names($1, $2);
2467
$_$;
2468
2469
2470
--
2471
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2472
--
2473
2474 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2475
idempotent.
2476
alters the names table, so it will need to be repopulated after running this function.
2477
';
2478 10297 aaronmk
2479
2480
--
2481 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2482 8143 aaronmk
--
2483
2484
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2485
    LANGUAGE sql STRICT
2486
    AS $_$
2487 10152 aaronmk
SELECT util.drop_table($1);
2488 8183 aaronmk
SELECT util.mk_map_table($1);
2489 8143 aaronmk
$_$;
2490
2491
2492
--
2493 12356 aaronmk
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2494
--
2495
2496
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2497
    LANGUAGE sql IMMUTABLE
2498
    AS $_$
2499
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2500
$_$;
2501
2502
2503
--
2504 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2505
--
2506
2507
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2508
    LANGUAGE plpgsql STRICT
2509
    AS $_$
2510
DECLARE
2511
	result text = NULL;
2512
BEGIN
2513
	BEGIN
2514
		result = util.show_create_view(view_);
2515
		PERFORM util.eval($$DROP VIEW $$||view_);
2516
	EXCEPTION
2517
		WHEN undefined_table THEN NULL;
2518
	END;
2519
	RETURN result;
2520
END;
2521
$_$;
2522
2523
2524
--
2525 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2526
--
2527
2528
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2529
    LANGUAGE sql
2530
    AS $_$
2531 12269 aaronmk
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2532 11660 aaronmk
$_$;
2533
2534
2535
--
2536 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2537
--
2538
2539
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2540
    LANGUAGE sql STABLE
2541
    AS $_$
2542
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2543
$_$;
2544
2545
2546
--
2547 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2548
--
2549
2550
CREATE FUNCTION schema(table_ regclass) RETURNS text
2551
    LANGUAGE sql STABLE
2552
    AS $_$
2553 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2554 12242 aaronmk
$_$;
2555
2556
2557
--
2558 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2559
--
2560
2561
CREATE FUNCTION schema(type regtype) RETURNS text
2562
    LANGUAGE sql STABLE
2563
    AS $_$
2564 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2565 10794 aaronmk
$_$;
2566
2567
2568
--
2569
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2570
--
2571
2572
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2573
    LANGUAGE sql STABLE
2574
    AS $_$
2575
SELECT util.schema(pg_typeof($1))
2576
$_$;
2577
2578
2579
--
2580 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2581
--
2582
2583
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2584
    LANGUAGE sql STABLE
2585
    AS $_$
2586
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2587
$_$;
2588
2589
2590
--
2591 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2592
--
2593
2594 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2595
a schema bundle is a group of schemas with a common prefix
2596
';
2597 12135 aaronmk
2598
2599
--
2600
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2601
--
2602
2603
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2604
    LANGUAGE sql
2605
    AS $_$
2606
SELECT util.schema_rename(old_schema,
2607
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2608
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2609
SELECT NULL::void; -- don't fold away functions called in previous query
2610
$_$;
2611
2612
2613
--
2614
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2615
--
2616
2617
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2618
    LANGUAGE plpgsql
2619
    AS $$
2620
BEGIN
2621
	-- don't schema_bundle_rm() the schema_bundle to keep!
2622
	IF replace = with_ THEN RETURN; END IF;
2623
2624
	PERFORM util.schema_bundle_rm(replace);
2625
	PERFORM util.schema_bundle_rename(with_, replace);
2626
END;
2627
$$;
2628
2629
2630
--
2631
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2632
--
2633
2634
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2635
    LANGUAGE sql
2636
    AS $_$
2637
SELECT util.schema_rm(schema)
2638
FROM util.schema_bundle_get_schemas($1) f (schema);
2639
SELECT NULL::void; -- don't fold away functions called in previous query
2640
$_$;
2641
2642
2643
--
2644 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2645 10795 aaronmk
--
2646
2647 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2648 10795 aaronmk
    LANGUAGE sql STABLE
2649
    AS $_$
2650
SELECT quote_ident(util.schema($1))
2651
$_$;
2652
2653
2654
--
2655 12324 aaronmk
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2656
--
2657
2658
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2659 12334 aaronmk
    LANGUAGE sql IMMUTABLE
2660 12324 aaronmk
    AS $_$
2661
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2662
$_$;
2663
2664
2665
--
2666 12304 aaronmk
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2667
--
2668
2669
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2670
    LANGUAGE sql STABLE
2671
    AS $_$
2672
SELECT oid FROM pg_namespace WHERE nspname = $1
2673
$_$;
2674
2675
2676
--
2677 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2678
--
2679
2680
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2681
    LANGUAGE sql
2682
    AS $_$
2683
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2684
$_$;
2685
2686
2687
--
2688 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2689
--
2690
2691
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2692
    LANGUAGE plpgsql
2693
    AS $$
2694
BEGIN
2695
	-- don't schema_rm() the schema to keep!
2696
	IF replace = with_ THEN RETURN; END IF;
2697
2698
	PERFORM util.schema_rm(replace);
2699
	PERFORM util.schema_rename(with_, replace);
2700
END;
2701
$$;
2702
2703
2704
--
2705 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2706
--
2707
2708
CREATE FUNCTION schema_rm(schema text) RETURNS void
2709
    LANGUAGE sql
2710
    AS $_$
2711
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2712
$_$;
2713
2714
2715
--
2716 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2717
--
2718
2719
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2720
    LANGUAGE sql STRICT
2721
    AS $_$
2722
SELECT util.eval(
2723
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2724
$_$;
2725
2726
2727
--
2728 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2729 8153 aaronmk
--
2730
2731
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2732
    LANGUAGE plpgsql STRICT
2733
    AS $_$
2734
DECLARE
2735 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
2736
    new text[] = ARRAY(SELECT util.map_values(names));
2737 8153 aaronmk
BEGIN
2738
    old = old[1:array_length(new, 1)]; -- truncate to same length
2739 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2740
||$$ TO $$||quote_ident(value))
2741 10149 aaronmk
    FROM each(hstore(old, new))
2742
    WHERE value != key -- not same name
2743
    ;
2744 8153 aaronmk
END;
2745
$_$;
2746
2747
2748
--
2749 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2750 8153 aaronmk
--
2751
2752 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2753
idempotent
2754
';
2755 8153 aaronmk
2756
2757
--
2758 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2759
--
2760
2761
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2762
    LANGUAGE plpgsql STRICT
2763
    AS $_$
2764
DECLARE
2765
	row_ util.map;
2766
BEGIN
2767 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
2768
	BEGIN
2769
		PERFORM util.set_col_names(table_, names);
2770
	EXCEPTION
2771
		WHEN array_subscript_error THEN -- selective suppress
2772
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2773
				-- metadata cols not yet added
2774
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2775
			END IF;
2776
	END;
2777
2778 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2779 10145 aaronmk
	LOOP
2780 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
2781
			substring(row_."from" from 2));
2782 10145 aaronmk
	END LOOP;
2783
2784
	PERFORM util.set_col_names(table_, names);
2785
END;
2786
$_$;
2787
2788
2789
--
2790
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2791
--
2792
2793 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2794
idempotent.
2795
the metadata mappings must be *last* in the names table.
2796
';
2797 10145 aaronmk
2798
2799
--
2800 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2801 8107 aaronmk
--
2802
2803
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2804
    LANGUAGE plpgsql STRICT
2805
    AS $_$
2806
DECLARE
2807
    sql text = $$ALTER TABLE $$||table_||$$
2808
$$||NULLIF(array_to_string(ARRAY(
2809
    SELECT
2810
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2811
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2812
    FROM
2813
    (
2814
        SELECT
2815
          quote_ident(col_name) AS col_name_sql
2816 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
2817 8107 aaronmk
        , type AS target_type
2818
        FROM unnest(col_casts)
2819
    ) s
2820
    WHERE curr_type != target_type
2821
), '
2822
, '), '');
2823
BEGIN
2824 12251 aaronmk
    PERFORM util.debug_print_sql(sql);
2825 8107 aaronmk
    EXECUTE COALESCE(sql, '');
2826
END;
2827
$_$;
2828
2829
2830
--
2831 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2832 8107 aaronmk
--
2833
2834 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2835
idempotent
2836
';
2837 8107 aaronmk
2838
2839
--
2840 12302 aaronmk
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2841
--
2842
2843
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2844
    LANGUAGE sql STRICT
2845
    AS $_$
2846
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2847
$_$;
2848
2849
2850
--
2851 11651 aaronmk
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2852
--
2853
2854
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2855
    LANGUAGE sql STABLE
2856
    AS $_$
2857 11656 aaronmk
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2858
$$||util.show_grants_for($1)
2859 11651 aaronmk
$_$;
2860
2861
2862
--
2863 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2864
--
2865
2866
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2867
    LANGUAGE sql STABLE
2868
    AS $_$
2869 12269 aaronmk
SELECT string_agg(cmd, '')
2870 11655 aaronmk
FROM
2871
(
2872
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2873
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2874
$$ ELSE '' END) AS cmd
2875
	FROM util.grants_users() f (user_)
2876
) s
2877
$_$;
2878
2879
2880
--
2881 12325 aaronmk
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2882
--
2883
2884
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
2885
    LANGUAGE sql STABLE
2886
    AS $_$
2887
SELECT oid FROM pg_class
2888
WHERE relkind = ANY($3) AND relname ~ $1
2889
AND util.schema_matches(util.schema(relnamespace), $2)
2890
ORDER BY relname
2891
$_$;
2892
2893
2894
--
2895 12305 aaronmk
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
2896
--
2897
2898 12326 aaronmk
CREATE FUNCTION show_views_like(name_regexp text, schema text) RETURNS SETOF regclass
2899 12305 aaronmk
    LANGUAGE sql STABLE
2900
    AS $_$
2901 12328 aaronmk
SELECT view_
2902
FROM util.show_relations_like($1, types := ARRAY['v']) view_
2903
WHERE util.schema(view_) = $2
2904 12305 aaronmk
$_$;
2905
2906
2907
--
2908 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2909 8144 aaronmk
--
2910
2911
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2912 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
2913 8144 aaronmk
    AS $_$
2914
DECLARE
2915
    hstore hstore;
2916
BEGIN
2917
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2918
        table_||$$))$$ INTO STRICT hstore;
2919
    RETURN hstore;
2920
END;
2921
$_$;
2922
2923
2924
--
2925 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2926
--
2927
2928
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2929
    LANGUAGE sql STABLE STRICT
2930
    AS $_$
2931
SELECT COUNT(*) > 0 FROM pg_constraint
2932
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2933
$_$;
2934
2935
2936
--
2937
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2938
--
2939
2940 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2941
gets whether a status flag is set by the presence of a table constraint
2942
';
2943 10184 aaronmk
2944
2945
--
2946 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2947
--
2948
2949
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2950
    LANGUAGE sql STRICT
2951
    AS $_$
2952
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2953
||quote_ident($2)||$$ CHECK (true)$$)
2954
$_$;
2955
2956
2957
--
2958
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2959
--
2960
2961 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2962
stores a status flag by the presence of a table constraint.
2963
idempotent.
2964
';
2965 10182 aaronmk
2966
2967
--
2968 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2969
--
2970
2971
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2972
    LANGUAGE sql STABLE STRICT
2973
    AS $_$
2974
SELECT util.table_flag__get($1, 'nulls_mapped')
2975
$_$;
2976
2977
2978
--
2979
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2980
--
2981
2982 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2983
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2984
';
2985 10185 aaronmk
2986
2987
--
2988 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2989
--
2990
2991
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2992
    LANGUAGE sql STRICT
2993
    AS $_$
2994
SELECT util.table_flag__set($1, 'nulls_mapped')
2995
$_$;
2996
2997
2998
--
2999
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3000
--
3001
3002 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3003
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3004
idempotent.
3005
';
3006 10183 aaronmk
3007
3008
--
3009 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3010 8088 aaronmk
--
3011
3012
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3013
    LANGUAGE plpgsql STRICT
3014
    AS $_$
3015
DECLARE
3016
    row record;
3017
BEGIN
3018 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3019 8088 aaronmk
    LOOP
3020
        IF row.global_name != row.name THEN
3021
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3022
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3023
        END IF;
3024
    END LOOP;
3025
END;
3026
$_$;
3027
3028
3029
--
3030 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3031 8088 aaronmk
--
3032
3033 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3034
idempotent
3035
';
3036 8088 aaronmk
3037
3038
--
3039 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3040
--
3041
3042
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3043
    LANGUAGE sql STRICT
3044
    AS $_$
3045 10595 aaronmk
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3046 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
3047
$_$;
3048
3049
3050
--
3051
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3052
--
3053
3054 12235 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3055
trims table_ to include only columns in the original data.
3056
idempotent.
3057
';
3058 10365 aaronmk
3059
3060
--
3061 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3062 8142 aaronmk
--
3063
3064
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3065
    LANGUAGE plpgsql STRICT
3066
    AS $_$
3067
BEGIN
3068
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3069
END;
3070
$_$;
3071
3072
3073
--
3074 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3075 8142 aaronmk
--
3076
3077 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3078
idempotent
3079
';
3080 8142 aaronmk
3081
3082
--
3083 12357 aaronmk
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3084
--
3085
3086
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3087
    LANGUAGE sql IMMUTABLE
3088
    AS $_$
3089
SELECT '^(.*)'||util._if(util.name_was_truncated($1),
3090
util.regexp_quote(util.rtrim_n($1, $2)), util.regexp_quote($1)||'$')
3091
$_$;
3092
3093
3094
--
3095 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3096
--
3097
3098
CREATE FUNCTION try_create(sql text) RETURNS void
3099
    LANGUAGE plpgsql STRICT
3100
    AS $$
3101
BEGIN
3102 10146 aaronmk
    PERFORM util.eval(sql);
3103 8199 aaronmk
EXCEPTION
3104 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3105 8199 aaronmk
    WHEN undefined_column THEN NULL;
3106
    WHEN duplicate_column THEN NULL;
3107
END;
3108
$$;
3109
3110
3111
--
3112
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3113
--
3114
3115 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
3116
idempotent
3117
';
3118 8199 aaronmk
3119
3120
--
3121 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3122
--
3123
3124
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3125
    LANGUAGE sql STRICT
3126
    AS $_$
3127
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3128
$_$;
3129
3130
3131
--
3132
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3133
--
3134
3135 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3136
idempotent
3137
';
3138 8209 aaronmk
3139
3140
--
3141 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3142
--
3143
3144
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3145
    LANGUAGE sql IMMUTABLE
3146
    AS $_$
3147
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3148
$_$;
3149
3150
3151
--
3152 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3153
--
3154
3155 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3156
a type''s NOT NULL qualifier
3157
';
3158 10161 aaronmk
3159
3160
--
3161 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3162
--
3163
3164 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3165
    LANGUAGE plpgsql STABLE
3166 8185 aaronmk
    AS $_$
3167
DECLARE
3168
    type regtype;
3169
BEGIN
3170 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3171
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3172 8185 aaronmk
    RETURN type;
3173
END;
3174
$_$;
3175
3176
3177
--
3178 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3179
--
3180
3181
CREATE AGGREGATE all_same(anyelement) (
3182
    SFUNC = all_same_transform,
3183
    STYPE = anyarray,
3184
    FINALFUNC = all_same_final
3185
);
3186
3187
3188
--
3189
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3190
--
3191
3192 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
3193
includes NULLs in comparison
3194
';
3195 9959 aaronmk
3196
3197
--
3198 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3199 2595 aaronmk
--
3200
3201
CREATE AGGREGATE join_strs(text, text) (
3202 4052 aaronmk
    SFUNC = join_strs_transform,
3203 4010 aaronmk
    STYPE = text
3204 2595 aaronmk
);
3205
3206
3207 8147 aaronmk
--
3208 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3209 8147 aaronmk
--
3210
3211
CREATE OPERATOR -> (
3212
    PROCEDURE = map_get,
3213
    LEFTARG = regclass,
3214
    RIGHTARG = text
3215
);
3216
3217
3218 10308 aaronmk
--
3219
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3220
--
3221
3222
CREATE OPERATOR => (
3223
    PROCEDURE = hstore,
3224 10357 aaronmk
    LEFTARG = text[],
3225 10608 aaronmk
    RIGHTARG = text
3226 10308 aaronmk
);
3227
3228
3229
--
3230 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3231 10308 aaronmk
--
3232
3233 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
3234
usage: array[''key1'', ...]::text[] => ''value''
3235
';
3236 10308 aaronmk
3237
3238 10391 aaronmk
--
3239 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3240
--
3241
3242
CREATE OPERATOR ?*>= (
3243
    PROCEDURE = is_populated_more_often_than,
3244
    LEFTARG = anyelement,
3245
    RIGHTARG = anyelement
3246
);
3247
3248
3249
--
3250 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3251
--
3252
3253
CREATE OPERATOR ?>= (
3254
    PROCEDURE = is_more_complete_than,
3255
    LEFTARG = anyelement,
3256
    RIGHTARG = anyelement
3257
);
3258
3259
3260 11005 aaronmk
--
3261
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3262
--
3263
3264
CREATE OPERATOR ||% (
3265
    PROCEDURE = concat_esc,
3266
    LEFTARG = text,
3267
    RIGHTARG = text
3268
);
3269
3270
3271
--
3272
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3273
--
3274
3275 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
3276
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3277
';
3278 11005 aaronmk
3279
3280 2107 aaronmk
--
3281 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
3282 8140 aaronmk
--
3283
3284
CREATE TABLE map (
3285
    "from" text NOT NULL,
3286 8158 aaronmk
    "to" text,
3287
    filter text,
3288
    notes text
3289 8140 aaronmk
);
3290
3291
3292
--
3293 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3294
--
3295
3296
3297
3298
--
3299 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3300 8140 aaronmk
--
3301
3302
3303
3304
--
3305 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3306 8140 aaronmk
--
3307
3308
ALTER TABLE ONLY map
3309 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3310 8140 aaronmk
3311
3312
--
3313 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3314
--
3315
3316
ALTER TABLE ONLY map
3317
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3318
3319
3320
--
3321 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3322
--
3323
3324
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3325
3326
3327
--
3328 2136 aaronmk
-- PostgreSQL database dump complete
3329
--