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