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