Project

General

Profile

1 2094 aaronmk
--
2
-- PostgreSQL database dump
3
--
4
5
SET statement_timeout = 0;
6
SET client_encoding = 'UTF8';
7 6213 aaronmk
SET standard_conforming_strings = on;
8 2094 aaronmk
SET check_function_bodies = false;
9
SET client_min_messages = warning;
10
11
--
12 8183 aaronmk
-- Name: util; Type: SCHEMA; Schema: -; Owner: -
13 2094 aaronmk
--
14
15 8183 aaronmk
CREATE SCHEMA util;
16 2094 aaronmk
17
18 4982 aaronmk
--
19 8183 aaronmk
-- Name: SCHEMA util; Type: COMMENT; Schema: -; Owner: -
20 4982 aaronmk
--
21
22 8183 aaronmk
COMMENT ON SCHEMA util IS 'IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.';
23 4982 aaronmk
24
25 8183 aaronmk
SET search_path = util, pg_catalog;
26 2107 aaronmk
27 2094 aaronmk
--
28 8183 aaronmk
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
29 8107 aaronmk
--
30
31
CREATE TYPE col_cast AS (
32
	col_name text,
33
	type regtype
34
);
35
36
37
--
38 8183 aaronmk
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
39 8106 aaronmk
--
40
41
CREATE TYPE col_ref AS (
42
	table_ regclass,
43
	name text
44
);
45
46
47
--
48 8183 aaronmk
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
49 7673 aaronmk
--
50
51
CREATE TYPE compass_dir AS ENUM (
52
    'N',
53
    'E',
54
    'S',
55
    'W'
56
);
57
58
59
--
60 8183 aaronmk
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
61 2610 aaronmk
--
62
63
CREATE TYPE datatype AS ENUM (
64
    'str',
65
    'float'
66
);
67
68
69
--
70 8183 aaronmk
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
71 2596 aaronmk
--
72
73 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
74 3422 aaronmk
    LANGUAGE sql IMMUTABLE
75
    AS $_$
76 4501 aaronmk
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
77 3422 aaronmk
$_$;
78
79
80
--
81 8183 aaronmk
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
82 5937 aaronmk
--
83
84 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
85 5937 aaronmk
    LANGUAGE sql IMMUTABLE
86
    AS $_$
87
SELECT bool_and(value)
88
FROM
89
(VALUES
90
      ($1)
91
    , ($2)
92 5956 aaronmk
    , ($3)
93
    , ($4)
94
    , ($5)
95 5937 aaronmk
)
96
AS v (value)
97
$_$;
98
99
100
--
101 8183 aaronmk
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
102 5937 aaronmk
--
103
104 6437 aaronmk
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_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.';
105 5937 aaronmk
106
107
--
108 8183 aaronmk
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
109 7704 aaronmk
--
110
111
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
112
    LANGUAGE sql IMMUTABLE
113
    AS $_$
114
SELECT avg(value)
115
FROM
116
(VALUES
117
      ($1)
118
    , ($2)
119
    , ($3)
120
    , ($4)
121
    , ($5)
122
)
123
AS v (value)
124
$_$;
125
126
127
--
128 8183 aaronmk
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
129 7679 aaronmk
--
130
131
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
132
    LANGUAGE sql IMMUTABLE STRICT
133
    AS $_$
134 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)
135 7698 aaronmk
FROM
136
(
137
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
138
    UNION ALL
139 7702 aaronmk
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
140
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
141 7698 aaronmk
)
142
matches (g)
143 7679 aaronmk
$_$;
144
145
146
--
147 8183 aaronmk
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
148 7672 aaronmk
--
149
150 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
151 7672 aaronmk
    LANGUAGE sql IMMUTABLE
152
    AS $_$
153 8183 aaronmk
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
154 7672 aaronmk
FROM
155
(VALUES
156 7677 aaronmk
      ($1)
157 7672 aaronmk
    , ($2/60)
158
    , ($3/60/60)
159
)
160
AS v (value)
161
$_$;
162
163
164
--
165 8183 aaronmk
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
166 7723 aaronmk
--
167
168
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
169
    LANGUAGE sql IMMUTABLE
170
    AS $_$
171 8183 aaronmk
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
172 7723 aaronmk
$_$;
173
174
175
--
176 8183 aaronmk
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
177 4142 aaronmk
--
178
179
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
180
    LANGUAGE sql IMMUTABLE
181
    AS $_$
182
SELECT $1 = $2
183
$_$;
184
185
186
--
187 8183 aaronmk
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
188 7396 aaronmk
--
189
190
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
191
    LANGUAGE sql IMMUTABLE
192
    AS $_$
193
-- Fix dates after threshold date
194
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
195
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
196
$_$;
197
198
199
--
200 8183 aaronmk
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
201 4147 aaronmk
--
202
203
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
204
    LANGUAGE sql IMMUTABLE
205
    AS $_$
206
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
207
$_$;
208
209
210
--
211 8183 aaronmk
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
212 4147 aaronmk
--
213
214
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
215
    LANGUAGE sql IMMUTABLE
216
    AS $_$
217 8183 aaronmk
SELECT util._if($1 != '', $2, $3)
218 4147 aaronmk
$_$;
219
220
221
--
222 8183 aaronmk
-- Name: _join(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
223 4325 aaronmk
--
224
225
CREATE FUNCTION _join("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
226
    LANGUAGE sql IMMUTABLE
227
    AS $_$
228 7848 aaronmk
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
229 4325 aaronmk
$_$;
230
231
232
--
233 8183 aaronmk
-- Name: _join_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
234 5009 aaronmk
--
235
236
CREATE FUNCTION _join_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
237
    LANGUAGE sql IMMUTABLE
238
    AS $_$
239 7848 aaronmk
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
240 5009 aaronmk
$_$;
241
242
243
--
244 8183 aaronmk
-- Name: _label(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
245 3422 aaronmk
--
246
247 4683 aaronmk
CREATE FUNCTION _label(label anyelement, value anyelement) RETURNS anyelement
248 4682 aaronmk
    LANGUAGE sql IMMUTABLE
249
    AS $_$
250
SELECT coalesce($1 || ': ', '') || $2
251
$_$;
252 2596 aaronmk
253
254
--
255 8825 aaronmk
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
256
--
257
258
CREATE FUNCTION _lowercase(value text) RETURNS text
259
    LANGUAGE sql IMMUTABLE STRICT
260
    AS $_$
261
SELECT lower($1)
262
$_$;
263
264
265
--
266 8183 aaronmk
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
267 6222 aaronmk
--
268
269
CREATE FUNCTION _map(map hstore, value text) RETURNS text
270 7820 aaronmk
    LANGUAGE plpgsql IMMUTABLE STRICT
271 6222 aaronmk
    AS $$
272
DECLARE
273 6271 aaronmk
    match text := map -> value;
274 6222 aaronmk
BEGIN
275 6271 aaronmk
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
276
        match := map -> '*'; -- use default entry
277
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
278
        END IF;
279
    END IF;
280
281
    -- Interpret result
282 6243 aaronmk
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
283
    ELSIF match = '*' THEN RETURN value;
284
    ELSE RETURN match;
285 6222 aaronmk
    END IF;
286
END;
287
$$;
288
289
290
--
291 10314 aaronmk
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
292
--
293
294
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
295
    LANGUAGE plpgsql IMMUTABLE STRICT
296
    AS $$
297
DECLARE
298 10315 aaronmk
    result value%TYPE := util._map(map, value::text)::unknown;
299 10314 aaronmk
BEGIN
300
    RETURN result;
301
END;
302
$$;
303
304
305
--
306 8183 aaronmk
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
307 5408 aaronmk
--
308
309
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
310
    LANGUAGE sql IMMUTABLE
311
    AS $_$
312 7289 aaronmk
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
313 5408 aaronmk
$_$;
314
315
316
--
317 8183 aaronmk
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
318 2940 aaronmk
--
319
320 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
321 2940 aaronmk
    LANGUAGE sql IMMUTABLE
322
    AS $_$
323 8183 aaronmk
SELECT util.join_strs(value, '; ')
324 2940 aaronmk
FROM
325
(
326
    SELECT *
327
    FROM
328
    (
329
        SELECT
330
        DISTINCT ON (value)
331
        *
332
        FROM
333
        (VALUES
334 4012 aaronmk
              (1, $1)
335
            , (2, $2)
336
            , (3, $3)
337
            , (4, $4)
338
            , (5, $5)
339
            , (6, $6)
340
            , (7, $7)
341
            , (8, $8)
342
            , (9, $9)
343
            , (10, $10)
344 2940 aaronmk
        )
345
        AS v (sort_order, value)
346 4011 aaronmk
        WHERE value IS NOT NULL
347 2940 aaronmk
    )
348
    AS v
349
    ORDER BY sort_order
350
)
351
AS v
352
$_$;
353
354
355
--
356 8183 aaronmk
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
357 7140 aaronmk
--
358
359
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
360
    LANGUAGE sql IMMUTABLE
361
    AS $_$
362
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
363
$_$;
364
365
366
--
367 8183 aaronmk
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
368 6354 aaronmk
--
369
370
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
371
    LANGUAGE sql IMMUTABLE
372
    AS $_$
373 8183 aaronmk
SELECT util.join_strs(value, ' ')
374 6354 aaronmk
FROM
375
(
376
    SELECT *
377
    FROM
378
    (
379
        SELECT
380
        DISTINCT ON (value)
381
        *
382
        FROM
383
        (VALUES
384
              (1, $1)
385
            , (2, $2)
386
            , (3, $3)
387
            , (4, $4)
388
            , (5, $5)
389
            , (6, $6)
390
            , (7, $7)
391
            , (8, $8)
392
            , (9, $9)
393
            , (10, $10)
394
        )
395
        AS v (sort_order, value)
396
        WHERE value IS NOT NULL
397
    )
398
    AS v
399
    ORDER BY sort_order
400
)
401
AS v
402
$_$;
403
404
405
--
406 8183 aaronmk
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
407 5408 aaronmk
--
408
409
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
410
    LANGUAGE sql IMMUTABLE
411
    AS $_$
412 7289 aaronmk
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
413 5408 aaronmk
$_$;
414
415
416
--
417 8183 aaronmk
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
418 6316 aaronmk
--
419
420
CREATE FUNCTION _not(value boolean) RETURNS boolean
421
    LANGUAGE sql IMMUTABLE STRICT
422
    AS $_$
423
SELECT NOT $1
424
$_$;
425
426
427
--
428 8183 aaronmk
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
429 7104 aaronmk
--
430
431
CREATE FUNCTION _now() RETURNS timestamp with time zone
432
    LANGUAGE sql STABLE
433
    AS $$
434
SELECT now()
435
$$;
436
437
438
--
439 8183 aaronmk
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
440 2949 aaronmk
--
441
442 4475 aaronmk
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
443 2949 aaronmk
    LANGUAGE plpgsql IMMUTABLE
444
    AS $$
445
DECLARE
446 8183 aaronmk
    type util.datatype NOT NULL := type; -- add NOT NULL
447 2949 aaronmk
BEGIN
448 4475 aaronmk
    IF type = 'str' THEN RETURN nullif(value::text, "null");
449 2722 aaronmk
    -- Invalid value is ignored, but invalid null value generates error
450 2949 aaronmk
    ELSIF type = 'float' THEN
451 2722 aaronmk
        DECLARE
452
            -- Outside the try block so that invalid null value generates error
453 2949 aaronmk
            "null" double precision := "null"::double precision;
454 2722 aaronmk
        BEGIN
455 2949 aaronmk
            RETURN nullif(value::double precision, "null");
456 2722 aaronmk
        EXCEPTION
457 2949 aaronmk
            WHEN data_exception THEN RETURN value; -- ignore invalid value
458 2722 aaronmk
        END;
459 2610 aaronmk
    END IF;
460
END;
461
$$;
462
463
464
--
465 8183 aaronmk
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
466 4479 aaronmk
--
467
468
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
469
    LANGUAGE sql IMMUTABLE
470
    AS $_$
471 8183 aaronmk
SELECT util."_nullIf"($1, $2, $3::util.datatype)
472 4479 aaronmk
$_$;
473
474
475
--
476 8183 aaronmk
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
477 6355 aaronmk
--
478
479
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
480
    LANGUAGE sql IMMUTABLE
481
    AS $_$
482
SELECT bool_or(value)
483
FROM
484
(VALUES
485
      ($1)
486
    , ($2)
487
    , ($3)
488
    , ($4)
489
    , ($5)
490
)
491
AS v (value)
492
$_$;
493
494
495
--
496 8183 aaronmk
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
497 6437 aaronmk
--
498
499
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_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.';
500
501
502
--
503 8183 aaronmk
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
504 7706 aaronmk
--
505
506
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
507
    LANGUAGE sql IMMUTABLE
508
    AS $_$
509
SELECT $2 - $1
510
$_$;
511
512
513
--
514 8183 aaronmk
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
515 6793 aaronmk
--
516
517
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
518
    LANGUAGE sql IMMUTABLE STRICT
519
    AS $_$
520
SELECT regexp_split_to_table($1, $2)
521
$_$;
522
523
524
--
525 9959 aaronmk
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
526
--
527
528
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
529
    LANGUAGE sql IMMUTABLE
530
    AS $_$
531
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
532
$_$;
533
534
535
--
536
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
537
--
538
539
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
540
    LANGUAGE plpgsql IMMUTABLE
541
    AS $$
542
DECLARE
543
	value_cmp         state%TYPE = ARRAY[value];
544
	state             state%TYPE = COALESCE(state, value_cmp);
545
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
546
BEGIN
547
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
548
END;
549
$$;
550
551
552
--
553 10305 aaronmk
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
554
--
555
556
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
557
    LANGUAGE sql IMMUTABLE
558
    AS $_$
559
SELECT pg_catalog.array_fill($1, ARRAY[$2])
560
$_$;
561
562
563
--
564 10303 aaronmk
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
565
--
566
567
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
568 10354 aaronmk
    LANGUAGE sql IMMUTABLE
569 10303 aaronmk
    AS $_$
570 10321 aaronmk
SELECT util.array_length($1, 1)
571 10303 aaronmk
$_$;
572
573
574
--
575 10304 aaronmk
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
576
--
577
578
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
579 10354 aaronmk
    LANGUAGE sql IMMUTABLE
580 10304 aaronmk
    AS $_$
581 10354 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
582 10304 aaronmk
$_$;
583
584
585
--
586
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
587
--
588
589
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS 'returns 0 instead of NULL for empty arrays';
590
591
592
--
593 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
594 8104 aaronmk
--
595
596
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
597
    LANGUAGE sql STABLE STRICT
598
    AS $_$
599
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
600
$_$;
601
602
603
--
604 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
605 8105 aaronmk
--
606
607
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
608
    LANGUAGE plpgsql STRICT
609
    AS $_$
610
BEGIN
611
    -- not yet clustered (ARRAY[] compares NULLs literally)
612 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
613 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
614
    END IF;
615
END;
616
$_$;
617
618
619
--
620 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
621 8105 aaronmk
--
622
623
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
624
625
626
--
627 10136 aaronmk
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
628
--
629
630
CREATE FUNCTION col_comment(col col_ref) RETURNS text
631
    LANGUAGE plpgsql STABLE STRICT
632
    AS $$
633
DECLARE
634
	comment text;
635
BEGIN
636
	SELECT description
637
	FROM pg_attribute
638
	LEFT JOIN pg_description ON objoid = attrelid
639
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
640
	WHERE attrelid = col.table_ AND attname = col.name
641
	INTO STRICT comment
642
	;
643
	RETURN comment;
644
EXCEPTION
645
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
646
END;
647
$$;
648
649
650
--
651 10130 aaronmk
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
652
--
653
654
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
655
    LANGUAGE plpgsql STABLE STRICT
656
    AS $$
657
DECLARE
658
	default_sql text;
659
BEGIN
660
	SELECT adsrc
661
	FROM pg_attribute
662
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
663
	WHERE attrelid = col.table_ AND attname = col.name
664
	INTO STRICT default_sql
665
	;
666
	RETURN default_sql;
667
EXCEPTION
668
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
669
END;
670
$$;
671
672
673
--
674 10134 aaronmk
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
675
--
676
677
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
678
    LANGUAGE sql STABLE
679
    AS $_$
680
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
681
$_$;
682
683
684
--
685
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
686
--
687
688
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
689
690
691
--
692 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
693 8180 aaronmk
--
694
695
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
696
    LANGUAGE plpgsql STRICT
697
    AS $$
698
BEGIN
699 8183 aaronmk
    PERFORM util.col_type(col);
700 8180 aaronmk
    RETURN true;
701
EXCEPTION
702
    WHEN undefined_column THEN RETURN false;
703
END;
704
$$;
705
706
707
--
708 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
709 8084 aaronmk
--
710
711
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
712 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
713 8084 aaronmk
    AS $$
714
DECLARE
715 8183 aaronmk
    prefix text := util.name(type)||'.';
716 8084 aaronmk
BEGIN
717
    RETURN QUERY
718 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
719
        FROM util.col_names(type) f (name_);
720 8084 aaronmk
END;
721
$$;
722
723
724
--
725 8183 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
726 8082 aaronmk
--
727
728
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
729 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
730 8082 aaronmk
    AS $_$
731
BEGIN
732
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
733
END;
734
$_$;
735
736
737
--
738 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
739 8151 aaronmk
--
740
741
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
742
    LANGUAGE sql STABLE STRICT
743
    AS $_$
744
SELECT attname::text
745
FROM pg_attribute
746 10158 aaronmk
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
747 8151 aaronmk
ORDER BY attnum
748
$_$;
749
750
751
--
752 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
753 8106 aaronmk
--
754
755
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
756 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
757
    AS $$
758
DECLARE
759
    type regtype;
760
BEGIN
761
    SELECT atttypid FROM pg_attribute
762
    WHERE attrelid = col.table_ AND attname = col.name
763
    INTO STRICT type
764
    ;
765
    RETURN type;
766
EXCEPTION
767 8171 aaronmk
    WHEN no_data_found THEN
768 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
769
            concat('undefined column: ', col.name);
770 8169 aaronmk
END;
771
$$;
772 8106 aaronmk
773
774
--
775 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
776 8095 aaronmk
--
777
778
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
779
    LANGUAGE sql IMMUTABLE STRICT
780
    AS $_$
781
SELECT position($1 in $2) > 0 /*1-based offset*/
782
$_$;
783
784
785
--
786 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
787 8094 aaronmk
--
788
789
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
790
    LANGUAGE plpgsql STRICT
791
    AS $$
792
BEGIN
793 10146 aaronmk
    PERFORM util.eval(sql);
794 8094 aaronmk
EXCEPTION
795 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
796 10181 aaronmk
    WHEN duplicate_object THEN NULL; -- e.g. constraint
797 8103 aaronmk
    WHEN duplicate_column THEN NULL;
798 10244 aaronmk
    WHEN invalid_table_definition THEN
799
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
800
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
801
        END IF;
802 8094 aaronmk
END;
803
$$;
804
805
806
--
807 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
808 8094 aaronmk
--
809
810
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
811
812
813
--
814 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
815
--
816
817
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
818
    LANGUAGE sql STABLE STRICT
819
    AS $_$
820
SELECT util.eval2set($$
821
SELECT col
822
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
823
LEFT JOIN $$||$2||$$ ON "to" = col
824
WHERE "from" IS NULL
825
$$, NULL::text)
826
$_$;
827
828
829
--
830
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
831
--
832
833
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS 'gets table_''s derived columns (all the columns not in the names table)';
834
835
836
--
837 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
838
--
839
840
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
841
    LANGUAGE sql STRICT
842
    AS $_$
843
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
844
$_$;
845
846
847
--
848
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
849
--
850
851
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
852
853
854
--
855 10362 aaronmk
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
856
--
857
858
CREATE FUNCTION drop_column(col col_ref) RETURNS void
859
    LANGUAGE sql STRICT
860
    AS $_$
861
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
862
quote_ident($1.name))
863
$_$;
864
865
866
--
867
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
868
--
869
870
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
871
872
873
--
874 10150 aaronmk
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
875
--
876
877
CREATE FUNCTION drop_table(table_ text) RETURNS void
878
    LANGUAGE sql STRICT
879
    AS $_$
880
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
881
$_$;
882
883
884
--
885
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
886
--
887
888
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
889
890
891
--
892 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
893
--
894
895
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
896
    LANGUAGE sql IMMUTABLE
897
    AS $_$
898
SELECT util.array_fill($1, 0)
899
$_$;
900
901
902
--
903
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
904
--
905
906
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS 'constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)';
907
908
909
--
910 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
911 8086 aaronmk
--
912
913
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
914 8138 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
915 8086 aaronmk
    AS $_$
916 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
917 8086 aaronmk
$_$;
918
919
920
--
921 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
922
--
923
924
CREATE FUNCTION eval(sql text) RETURNS void
925
    LANGUAGE plpgsql STRICT
926
    AS $$
927
BEGIN
928
    RAISE NOTICE '%', sql;
929
    EXECUTE sql;
930
END;
931
$$;
932
933
934
--
935 10363 aaronmk
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
936
--
937
938
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
939
    LANGUAGE plpgsql
940
    AS $$
941
BEGIN
942
	RAISE NOTICE '%', sql;
943
	RETURN QUERY EXECUTE sql;
944
END;
945
$$;
946
947
948
--
949
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
950
--
951
952
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
953
954
955
--
956 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
957 10128 aaronmk
--
958
959 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
960 10128 aaronmk
    LANGUAGE plpgsql
961
    AS $$
962
DECLARE
963
	ret_val ret_type_null%TYPE;
964
BEGIN
965
	RAISE NOTICE '%', sql;
966
	EXECUTE sql INTO STRICT ret_val;
967
	RETURN ret_val;
968
END;
969
$$;
970
971
972
--
973 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
974 10128 aaronmk
--
975
976 10129 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
977 10128 aaronmk
978
979
--
980 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
981
--
982
983
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
984
    LANGUAGE sql
985
    AS $_$
986 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
987 10131 aaronmk
$_$;
988
989
990
--
991
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
992
--
993
994
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
995
996
997
--
998 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
999
--
1000
1001
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1002
    LANGUAGE sql
1003
    AS $_$
1004
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1005
$_$;
1006
1007
1008
--
1009
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1010
--
1011
1012
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1013
ret_type_null: NULL::ret_type';
1014
1015
1016
--
1017 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1018 8182 aaronmk
--
1019
1020
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1021
    LANGUAGE sql STABLE STRICT
1022
    AS $_$
1023
SELECT col_name
1024
FROM unnest($2) s (col_name)
1025 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1026 8182 aaronmk
$_$;
1027
1028
1029
--
1030 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1031
--
1032
1033
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1034 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1035 10323 aaronmk
    AS $_$
1036
-- STRICT handles NULLs, so that the array will always be a value
1037 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1038
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1039
) END
1040 10323 aaronmk
$_$;
1041
1042
1043
--
1044
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1045
--
1046
1047
COMMENT ON FUNCTION fix_array("array" anyarray) IS 'ensures that an array will always have proper non-NULL dimensions';
1048
1049
1050
--
1051 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1052
--
1053
1054
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1055
    LANGUAGE plpgsql STRICT
1056
    AS $_$
1057
DECLARE
1058
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1059
$$||query;
1060
BEGIN
1061
	EXECUTE mk_view;
1062
EXCEPTION
1063
WHEN invalid_table_definition THEN
1064 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1065
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1066
	THEN
1067 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1068
		EXECUTE mk_view;
1069
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1070
	END IF;
1071
END;
1072
$_$;
1073
1074
1075
--
1076
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1077
--
1078
1079
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1080
1081
1082
--
1083 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1084 8085 aaronmk
--
1085
1086
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1087
    LANGUAGE sql IMMUTABLE STRICT
1088
    AS $_$
1089
SELECT substring($2 for length($1)) = $1
1090
$_$;
1091
1092
1093
--
1094 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1095
--
1096
1097
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1098
    LANGUAGE sql IMMUTABLE
1099
    AS $_$
1100 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1101 10307 aaronmk
$_$;
1102
1103
1104
--
1105
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1106
--
1107
1108
COMMENT ON FUNCTION hstore(keys text[], value text) IS 'avoids repeating the same value for each key';
1109
1110
1111
--
1112 10356 aaronmk
-- Name: hstore(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1113
--
1114
1115
CREATE FUNCTION hstore(keys text[], value anyelement) RETURNS hstore
1116
    LANGUAGE sql IMMUTABLE
1117
    AS $_$
1118
SELECT util.hstore($1, $2::text)
1119
$_$;
1120
1121
1122
--
1123
-- Name: FUNCTION hstore(keys text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1124
--
1125
1126
COMMENT ON FUNCTION hstore(keys text[], value anyelement) IS 'avoids repeating the same value for each key';
1127
1128
1129
--
1130 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1131
--
1132
1133
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1134
    LANGUAGE sql STABLE STRICT
1135
    AS $_$
1136
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1137
$_$;
1138
1139
1140
--
1141 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1142 4009 aaronmk
--
1143
1144 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1145 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1146 4009 aaronmk
    AS $_$
1147 4054 aaronmk
SELECT $1 || $3 || $2
1148 2595 aaronmk
$_$;
1149
1150
1151
--
1152 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1153
--
1154
1155
CREATE FUNCTION map_filter_insert() RETURNS trigger
1156
    LANGUAGE plpgsql
1157
    AS $$
1158
BEGIN
1159
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1160
	RETURN new;
1161
END;
1162
$$;
1163
1164
1165
--
1166 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1167 8146 aaronmk
--
1168
1169
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1170
    LANGUAGE plpgsql STABLE STRICT
1171
    AS $_$
1172
DECLARE
1173
    value text;
1174
BEGIN
1175
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1176 8149 aaronmk
        INTO value USING key;
1177 8146 aaronmk
    RETURN value;
1178
END;
1179
$_$;
1180
1181
1182
--
1183 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1184 10325 aaronmk
--
1185
1186 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1187 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1188 10325 aaronmk
    AS $_$
1189 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1190 10325 aaronmk
$_$;
1191
1192
1193
--
1194 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1195
--
1196
1197
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS 'due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
1198
1199
[1] inlining of function calls, which is different from constant folding
1200
[2] _map()''s profiling query
1201
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1202
and map_nulls()''s profiling query
1203
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1204
both take ~920 ms';
1205
1206
1207
--
1208 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1209 8150 aaronmk
--
1210
1211
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1212
    LANGUAGE plpgsql STABLE STRICT
1213
    AS $_$
1214
BEGIN
1215
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1216
END;
1217
$_$;
1218
1219
1220
--
1221 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1222
--
1223
1224
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1225
    LANGUAGE sql STRICT
1226
    AS $_$
1227 10135 aaronmk
SELECT util.create_if_not_exists($$
1228
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1229 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1230 10135 aaronmk
||quote_literal($2)||$$;
1231
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1232
$$)
1233 8190 aaronmk
$_$;
1234
1235
1236
--
1237
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1238
--
1239
1240
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1241
1242
1243
--
1244 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1245 8187 aaronmk
--
1246
1247 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1248 8187 aaronmk
    LANGUAGE plpgsql STRICT
1249
    AS $_$
1250
DECLARE
1251
    type regtype = util.typeof(expr, col.table_::text::regtype);
1252
    col_name_sql text = quote_ident(col.name);
1253
BEGIN
1254 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1255
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1256 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1257
$$||expr||$$;
1258
$$);
1259
END;
1260
$_$;
1261
1262
1263
--
1264 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1265 8188 aaronmk
--
1266
1267 10296 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS 'idempotent';
1268 8188 aaronmk
1269
1270
--
1271 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1272 8139 aaronmk
--
1273
1274
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1275 8141 aaronmk
    LANGUAGE sql STRICT
1276 8139 aaronmk
    AS $_$
1277 8183 aaronmk
SELECT util.create_if_not_exists($$
1278 8141 aaronmk
CREATE TABLE $$||$1||$$
1279 8139 aaronmk
(
1280 8183 aaronmk
    LIKE util.map INCLUDING ALL
1281 10110 aaronmk
);
1282
1283
CREATE TRIGGER map_filter_insert
1284
  BEFORE INSERT
1285
  ON $$||$1||$$
1286
  FOR EACH ROW
1287
  EXECUTE PROCEDURE util.map_filter_insert();
1288 8141 aaronmk
$$)
1289 8139 aaronmk
$_$;
1290
1291
1292
--
1293 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1294
--
1295
1296
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1297
    LANGUAGE sql STRICT
1298
    AS $_$
1299
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1300
$_$;
1301
1302
1303
--
1304
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1305
--
1306
1307
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1308
1309
1310
--
1311 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1312
--
1313
1314
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1315
    LANGUAGE plpgsql STRICT
1316
    AS $_$
1317
BEGIN
1318
	EXECUTE $$
1319
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1320
  RETURNS SETOF $$||view_||$$ AS
1321
$BODY1$
1322
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$
1323 8331 aaronmk
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN COALESCE($2, 0)+1 AND COALESCE(COALESCE($2, 0)+1 + $1 - 1, 2147483647)
1324 8325 aaronmk
$BODY1$
1325
  LANGUAGE sql STABLE
1326
  COST 100
1327
  ROWS 1000
1328
$$;
1329 8326 aaronmk
-- Also create subset function which turns off enable_sort
1330
	EXECUTE $$
1331
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1332
  RETURNS SETOF $$||view_||$$
1333
  SET enable_sort TO 'off'
1334
  AS
1335
$BODY1$
1336 8328 aaronmk
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$($2, $3)
1337 8326 aaronmk
$BODY1$
1338
  LANGUAGE sql STABLE
1339
  COST 100
1340
  ROWS 1000
1341
;
1342
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1343
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1344
If you want to run EXPLAIN and get expanded output, use the regular subset
1345
function instead. (When a config param is set on a function, EXPLAIN produces
1346
just a function scan.)
1347
';
1348
$$;
1349 8325 aaronmk
END;
1350
$_$;
1351
1352
1353
--
1354 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1355 8083 aaronmk
--
1356
1357
CREATE FUNCTION name(type regtype) RETURNS text
1358 8097 aaronmk
    LANGUAGE sql STABLE STRICT
1359 8083 aaronmk
    AS $_$
1360
SELECT typname::text FROM pg_type WHERE oid = $1
1361
$_$;
1362
1363
1364
--
1365 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1366
--
1367
1368
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1369
    LANGUAGE sql IMMUTABLE
1370
    AS $_$
1371 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1372 9958 aaronmk
$_$;
1373
1374
1375
--
1376 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1377
--
1378
1379
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1380 9957 aaronmk
    LANGUAGE sql IMMUTABLE
1381 9956 aaronmk
    AS $_$
1382
SELECT $1 IS NOT NULL
1383
$_$;
1384
1385
1386
--
1387 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1388
--
1389
1390
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1391
    LANGUAGE sql IMMUTABLE
1392
    AS $_$
1393
SELECT util.hstore($1, NULL) || '*=>*'
1394
$_$;
1395
1396
1397
--
1398
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1399
--
1400
1401
COMMENT ON FUNCTION nulls_map(nulls text[]) IS 'for use with _map()';
1402
1403
1404
--
1405 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1406
--
1407
1408
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1409
    LANGUAGE plpgsql IMMUTABLE STRICT
1410
    AS $$
1411
BEGIN
1412
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1413
END;
1414
$$;
1415
1416
1417
--
1418 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1419 8137 aaronmk
--
1420
1421 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1422 8137 aaronmk
    LANGUAGE sql STRICT
1423
    AS $_$
1424 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1425 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1426 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
1427
SELECT NULL::void; -- don't fold away functions called in previous query
1428 8137 aaronmk
$_$;
1429
1430
1431
--
1432 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1433 8137 aaronmk
--
1434
1435 8148 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1436 8137 aaronmk
1437
1438
--
1439 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1440
--
1441
1442
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1443
    LANGUAGE sql STRICT
1444
    AS $_$
1445
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1446
SELECT util.set_col_names($1, $2);
1447
$_$;
1448
1449
1450
--
1451
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1452
--
1453
1454
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS 'idempotent.
1455
alters the names table, so it will need to be repopulated after running this function.';
1456
1457
1458
--
1459 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1460 8143 aaronmk
--
1461
1462
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1463
    LANGUAGE sql STRICT
1464
    AS $_$
1465 10152 aaronmk
SELECT util.drop_table($1);
1466 8183 aaronmk
SELECT util.mk_map_table($1);
1467 8143 aaronmk
$_$;
1468
1469
1470
--
1471 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1472
--
1473
1474
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1475
    LANGUAGE sql STRICT
1476
    AS $_$
1477
SELECT util.eval(
1478
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1479
$_$;
1480
1481
1482
--
1483 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1484 8153 aaronmk
--
1485
1486
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1487
    LANGUAGE plpgsql STRICT
1488
    AS $_$
1489
DECLARE
1490 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
1491
    new text[] = ARRAY(SELECT util.map_values(names));
1492 8153 aaronmk
BEGIN
1493
    old = old[1:array_length(new, 1)]; -- truncate to same length
1494 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
1495
||$$ TO $$||quote_ident(value))
1496 10149 aaronmk
    FROM each(hstore(old, new))
1497
    WHERE value != key -- not same name
1498
    ;
1499 8153 aaronmk
END;
1500
$_$;
1501
1502
1503
--
1504 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1505 8153 aaronmk
--
1506
1507
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1508
1509
1510
--
1511 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1512
--
1513
1514
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1515
    LANGUAGE plpgsql STRICT
1516
    AS $_$
1517
DECLARE
1518
	row_ util.map;
1519
BEGIN
1520 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1521 10145 aaronmk
	LOOP
1522 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
1523
			substring(row_."from" from 2));
1524 10145 aaronmk
	END LOOP;
1525
1526
	PERFORM util.set_col_names(table_, names);
1527
END;
1528
$_$;
1529
1530
1531
--
1532
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1533
--
1534
1535
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS 'idempotent.
1536 10157 aaronmk
the metadata mappings must be *last* in the names table.';
1537 10145 aaronmk
1538
1539
--
1540 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1541 8107 aaronmk
--
1542
1543
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1544
    LANGUAGE plpgsql STRICT
1545
    AS $_$
1546
DECLARE
1547
    sql text = $$ALTER TABLE $$||table_||$$
1548
$$||NULLIF(array_to_string(ARRAY(
1549
    SELECT
1550
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1551
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1552
    FROM
1553
    (
1554
        SELECT
1555
          quote_ident(col_name) AS col_name_sql
1556 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
1557 8107 aaronmk
        , type AS target_type
1558
        FROM unnest(col_casts)
1559
    ) s
1560
    WHERE curr_type != target_type
1561
), '
1562
, '), '');
1563
BEGIN
1564
    RAISE NOTICE '%', sql;
1565
    EXECUTE COALESCE(sql, '');
1566
END;
1567
$_$;
1568
1569
1570
--
1571 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1572 8107 aaronmk
--
1573
1574
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS 'idempotent';
1575
1576
1577
--
1578 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1579 8144 aaronmk
--
1580
1581
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1582 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
1583 8144 aaronmk
    AS $_$
1584
DECLARE
1585
    hstore hstore;
1586
BEGIN
1587
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1588
        table_||$$))$$ INTO STRICT hstore;
1589
    RETURN hstore;
1590
END;
1591
$_$;
1592
1593
1594
--
1595 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1596
--
1597
1598
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
1599
    LANGUAGE sql STABLE STRICT
1600
    AS $_$
1601
SELECT COUNT(*) > 0 FROM pg_constraint
1602
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
1603
$_$;
1604
1605
1606
--
1607
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1608
--
1609
1610
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS 'gets whether a status flag is set by the presence of a table constraint';
1611
1612
1613
--
1614 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1615
--
1616
1617
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
1618
    LANGUAGE sql STRICT
1619
    AS $_$
1620
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
1621
||quote_ident($2)||$$ CHECK (true)$$)
1622
$_$;
1623
1624
1625
--
1626
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1627
--
1628
1629
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS 'stores a status flag by the presence of a table constraint.
1630
idempotent.';
1631
1632
1633
--
1634 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
1635
--
1636
1637
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
1638
    LANGUAGE sql STABLE STRICT
1639
    AS $_$
1640
SELECT util.table_flag__get($1, 'nulls_mapped')
1641
$_$;
1642
1643
1644
--
1645
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1646
--
1647
1648
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS 'gets whether a table''s NULL-equivalent strings have been replaced with NULL';
1649
1650
1651
--
1652 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
1653
--
1654
1655
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
1656
    LANGUAGE sql STRICT
1657
    AS $_$
1658
SELECT util.table_flag__set($1, 'nulls_mapped')
1659
$_$;
1660
1661
1662
--
1663
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1664
--
1665
1666
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS 'sets that a table''s NULL-equivalent strings have been replaced with NULL.
1667
idempotent.';
1668
1669
1670
--
1671 10112 aaronmk
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1672
--
1673
1674
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1675
    LANGUAGE sql STABLE STRICT
1676
    AS $_$
1677
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1678
$_$;
1679
1680
1681
--
1682 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1683 8088 aaronmk
--
1684
1685
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1686
    LANGUAGE plpgsql STRICT
1687
    AS $_$
1688
DECLARE
1689
    row record;
1690
BEGIN
1691 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1692 8088 aaronmk
    LOOP
1693
        IF row.global_name != row.name THEN
1694
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1695
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1696
        END IF;
1697
    END LOOP;
1698
END;
1699
$_$;
1700
1701
1702
--
1703 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1704 8088 aaronmk
--
1705
1706
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1707
1708
1709
--
1710 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1711
--
1712
1713
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
1714
    LANGUAGE sql STRICT
1715
    AS $_$
1716
SELECT util.drop_column(($1, col)) FROM util.derived_cols($1, $2) f (col);
1717
SELECT NULL::void; -- don't fold away functions called in previous query
1718
$_$;
1719
1720
1721
--
1722
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1723
--
1724
1725
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS 'trims table_ to include only original columns, as defined by the names table.
1726
idempotent.';
1727
1728
1729
--
1730 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1731 8142 aaronmk
--
1732
1733
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1734
    LANGUAGE plpgsql STRICT
1735
    AS $_$
1736
BEGIN
1737
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1738
END;
1739
$_$;
1740
1741
1742
--
1743 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1744 8142 aaronmk
--
1745
1746
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1747
1748
1749
--
1750 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1751
--
1752
1753
CREATE FUNCTION try_create(sql text) RETURNS void
1754
    LANGUAGE plpgsql STRICT
1755
    AS $$
1756
BEGIN
1757 10146 aaronmk
    PERFORM util.eval(sql);
1758 8199 aaronmk
EXCEPTION
1759 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1760 8199 aaronmk
    WHEN undefined_column THEN NULL;
1761
    WHEN duplicate_column THEN NULL;
1762
END;
1763
$$;
1764
1765
1766
--
1767
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1768
--
1769
1770
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1771
1772
1773
--
1774 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1775
--
1776
1777
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1778
    LANGUAGE sql STRICT
1779
    AS $_$
1780
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1781
$_$;
1782
1783
1784
--
1785
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1786
--
1787
1788
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1789
1790
1791
--
1792 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1793
--
1794
1795
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1796
    LANGUAGE sql IMMUTABLE
1797
    AS $_$
1798
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1799
$_$;
1800
1801
1802
--
1803 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
1804
--
1805
1806
COMMENT ON FUNCTION type_qual(value anyelement) IS 'a type''s NOT NULL qualifier';
1807
1808
1809
--
1810 8324 aaronmk
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
1811
--
1812
1813
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1814
    LANGUAGE sql STABLE STRICT
1815
    SET search_path TO pg_temp
1816
    AS $_$
1817
SELECT $1::text
1818
$_$;
1819
1820
1821
--
1822 10161 aaronmk
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
1823
--
1824
1825
COMMENT ON FUNCTION type_qual_name(type regtype) IS 'a type''s schema-qualified name';
1826
1827
1828
--
1829 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
1830
--
1831
1832 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
1833
    LANGUAGE plpgsql STABLE
1834 8185 aaronmk
    AS $_$
1835
DECLARE
1836
    type regtype;
1837
BEGIN
1838 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
1839
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
1840 8185 aaronmk
    RETURN type;
1841
END;
1842
$_$;
1843
1844
1845
--
1846 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
1847
--
1848
1849
CREATE AGGREGATE all_same(anyelement) (
1850
    SFUNC = all_same_transform,
1851
    STYPE = anyarray,
1852
    FINALFUNC = all_same_final
1853
);
1854
1855
1856
--
1857
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
1858
--
1859
1860
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
1861
1862
1863
--
1864 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1865 2595 aaronmk
--
1866
1867
CREATE AGGREGATE join_strs(text, text) (
1868 4052 aaronmk
    SFUNC = join_strs_transform,
1869 4010 aaronmk
    STYPE = text
1870 2595 aaronmk
);
1871
1872
1873 8147 aaronmk
--
1874 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1875 8147 aaronmk
--
1876
1877
CREATE OPERATOR -> (
1878
    PROCEDURE = map_get,
1879
    LEFTARG = regclass,
1880
    RIGHTARG = text
1881
);
1882
1883
1884 10308 aaronmk
--
1885
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
1886
--
1887
1888
CREATE OPERATOR => (
1889
    PROCEDURE = hstore,
1890 10357 aaronmk
    LEFTARG = text[],
1891 10327 aaronmk
    RIGHTARG = anyelement
1892 10308 aaronmk
);
1893
1894
1895
--
1896 10357 aaronmk
-- Name: OPERATOR => (text[], anyelement); Type: COMMENT; Schema: util; Owner: -
1897 10308 aaronmk
--
1898
1899 10357 aaronmk
COMMENT ON OPERATOR => (text[], anyelement) IS 'usage: array[''key1'', ...]::text[] => ''value''';
1900 10308 aaronmk
1901
1902 8140 aaronmk
SET default_tablespace = '';
1903
1904
SET default_with_oids = false;
1905
1906 2107 aaronmk
--
1907 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
1908 8140 aaronmk
--
1909
1910
CREATE TABLE map (
1911
    "from" text NOT NULL,
1912 8158 aaronmk
    "to" text,
1913
    filter text,
1914
    notes text
1915 8140 aaronmk
);
1916
1917
1918
--
1919 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
1920 8140 aaronmk
--
1921
1922
1923
1924
--
1925 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
1926 8140 aaronmk
--
1927
1928
ALTER TABLE ONLY map
1929 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
1930 8140 aaronmk
1931
1932
--
1933 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
1934
--
1935
1936
ALTER TABLE ONLY map
1937
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
1938
1939
1940
--
1941 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
1942
--
1943
1944
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
1945
1946
1947
--
1948 2136 aaronmk
-- PostgreSQL database dump complete
1949
--