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