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 11005 aaronmk
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
819
--
820
821
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
822
    LANGUAGE sql IMMUTABLE
823
    AS $_$
824
SELECT util.esc_name__append($2, $1)
825
$_$;
826
827
828
--
829 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
830 8095 aaronmk
--
831
832
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
833 10388 aaronmk
    LANGUAGE sql IMMUTABLE
834 8095 aaronmk
    AS $_$
835
SELECT position($1 in $2) > 0 /*1-based offset*/
836
$_$;
837
838
839
--
840 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
841 8094 aaronmk
--
842
843
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
844
    LANGUAGE plpgsql STRICT
845
    AS $$
846
BEGIN
847 10146 aaronmk
    PERFORM util.eval(sql);
848 8094 aaronmk
EXCEPTION
849 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
850 10181 aaronmk
    WHEN duplicate_object THEN NULL; -- e.g. constraint
851 8103 aaronmk
    WHEN duplicate_column THEN NULL;
852 10244 aaronmk
    WHEN invalid_table_definition THEN
853
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
854
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
855
        END IF;
856 8094 aaronmk
END;
857
$$;
858
859
860
--
861 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
862 8094 aaronmk
--
863
864
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
865
866
867
--
868 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
869
--
870
871
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
872
    LANGUAGE sql STABLE STRICT
873
    AS $_$
874
SELECT util.eval2set($$
875
SELECT col
876
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
877
LEFT JOIN $$||$2||$$ ON "to" = col
878
WHERE "from" IS NULL
879
$$, NULL::text)
880
$_$;
881
882
883
--
884
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
885
--
886
887
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS 'gets table_''s derived columns (all the columns not in the names table)';
888
889
890
--
891 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
892
--
893
894
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
895
    LANGUAGE sql STRICT
896
    AS $_$
897
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
898
$_$;
899
900
901
--
902
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
903
--
904
905
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
906
907
908
--
909 10362 aaronmk
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
910
--
911
912
CREATE FUNCTION drop_column(col col_ref) RETURNS void
913
    LANGUAGE sql STRICT
914
    AS $_$
915
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
916
quote_ident($1.name))
917
$_$;
918
919
920
--
921
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
922
--
923
924
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
925
926
927
--
928 10150 aaronmk
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
929
--
930
931
CREATE FUNCTION drop_table(table_ text) RETURNS void
932
    LANGUAGE sql STRICT
933
    AS $_$
934
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
935
$_$;
936
937
938
--
939
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
940
--
941
942
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
943
944
945
--
946 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
947
--
948
949
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
950
    LANGUAGE sql IMMUTABLE
951
    AS $_$
952
SELECT util.array_fill($1, 0)
953
$_$;
954
955
956
--
957
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
958
--
959
960
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)';
961
962
963
--
964 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
965 8086 aaronmk
--
966
967
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
968 10388 aaronmk
    LANGUAGE sql IMMUTABLE
969 8086 aaronmk
    AS $_$
970 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
971 8086 aaronmk
$_$;
972
973
974
--
975 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
976
--
977
978
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
979
    LANGUAGE sql IMMUTABLE
980
    AS $_$
981
SELECT regexp_replace($2, '("?)$', $1||'\1')
982
$_$;
983
984
985
--
986 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
987
--
988
989
CREATE FUNCTION eval(sql text) RETURNS void
990
    LANGUAGE plpgsql STRICT
991
    AS $$
992
BEGIN
993
    RAISE NOTICE '%', sql;
994
    EXECUTE sql;
995
END;
996
$$;
997
998
999
--
1000 10363 aaronmk
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1001
--
1002
1003
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1004
    LANGUAGE plpgsql
1005
    AS $$
1006
BEGIN
1007
	RAISE NOTICE '%', sql;
1008
	RETURN QUERY EXECUTE sql;
1009
END;
1010
$$;
1011
1012
1013
--
1014
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1015
--
1016
1017
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
1018
1019
1020
--
1021 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1022 10128 aaronmk
--
1023
1024 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1025 10128 aaronmk
    LANGUAGE plpgsql
1026
    AS $$
1027
DECLARE
1028
	ret_val ret_type_null%TYPE;
1029
BEGIN
1030
	RAISE NOTICE '%', sql;
1031
	EXECUTE sql INTO STRICT ret_val;
1032
	RETURN ret_val;
1033
END;
1034
$$;
1035
1036
1037
--
1038 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1039 10128 aaronmk
--
1040
1041 10129 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
1042 10128 aaronmk
1043
1044
--
1045 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1046
--
1047
1048
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1049
    LANGUAGE sql
1050
    AS $_$
1051 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1052 10131 aaronmk
$_$;
1053
1054
1055
--
1056
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1057
--
1058
1059
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
1060
1061
1062
--
1063 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1064
--
1065
1066
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1067
    LANGUAGE sql
1068
    AS $_$
1069
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1070
$_$;
1071
1072
1073
--
1074
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1075
--
1076
1077
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1078
ret_type_null: NULL::ret_type';
1079
1080
1081
--
1082 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1083 8182 aaronmk
--
1084
1085
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1086
    LANGUAGE sql STABLE STRICT
1087
    AS $_$
1088
SELECT col_name
1089
FROM unnest($2) s (col_name)
1090 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1091 8182 aaronmk
$_$;
1092
1093
1094
--
1095 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1096
--
1097
1098
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1099 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1100 10323 aaronmk
    AS $_$
1101
-- STRICT handles NULLs, so that the array will always be a value
1102 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1103
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1104
) END
1105 10323 aaronmk
$_$;
1106
1107
1108
--
1109
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1110
--
1111
1112
COMMENT ON FUNCTION fix_array("array" anyarray) IS 'ensures that an array will always have proper non-NULL dimensions';
1113
1114
1115
--
1116 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1117
--
1118
1119
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1120
    LANGUAGE plpgsql STRICT
1121
    AS $_$
1122
DECLARE
1123
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1124
$$||query;
1125
BEGIN
1126
	EXECUTE mk_view;
1127
EXCEPTION
1128
WHEN invalid_table_definition THEN
1129 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1130
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1131
	THEN
1132 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1133
		EXECUTE mk_view;
1134
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1135
	END IF;
1136
END;
1137
$_$;
1138
1139
1140
--
1141
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1142
--
1143
1144
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1145
1146
1147
--
1148 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1149 8085 aaronmk
--
1150
1151
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1152 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1153 8085 aaronmk
    AS $_$
1154
SELECT substring($2 for length($1)) = $1
1155
$_$;
1156
1157
1158
--
1159 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1160
--
1161
1162
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1163
    LANGUAGE sql IMMUTABLE
1164
    AS $_$
1165 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1166 10307 aaronmk
$_$;
1167
1168
1169
--
1170
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1171
--
1172
1173
COMMENT ON FUNCTION hstore(keys text[], value text) IS 'avoids repeating the same value for each key';
1174
1175
1176
--
1177 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1178
--
1179
1180
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1181
    LANGUAGE sql STABLE STRICT
1182
    AS $_$
1183
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1184
$_$;
1185
1186
1187
--
1188 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1189
--
1190
1191
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1192
    LANGUAGE sql IMMUTABLE
1193
    AS $_$
1194
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1195
$_$;
1196
1197
1198
--
1199 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1200
--
1201
1202
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1203
    LANGUAGE sql IMMUTABLE
1204
    AS $_$
1205
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1206
$_$;
1207
1208
1209
--
1210 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1211 4009 aaronmk
--
1212
1213 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1214 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1215 4009 aaronmk
    AS $_$
1216 4054 aaronmk
SELECT $1 || $3 || $2
1217 2595 aaronmk
$_$;
1218
1219
1220
--
1221 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1222 10985 aaronmk
--
1223
1224 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1225 10985 aaronmk
    LANGUAGE sql IMMUTABLE
1226
    AS $_$
1227 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1228 10985 aaronmk
$_$;
1229
1230
1231
--
1232 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1233
--
1234
1235
CREATE FUNCTION map_filter_insert() RETURNS trigger
1236
    LANGUAGE plpgsql
1237
    AS $$
1238
BEGIN
1239
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1240
	RETURN new;
1241
END;
1242
$$;
1243
1244
1245
--
1246 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1247 8146 aaronmk
--
1248
1249
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1250
    LANGUAGE plpgsql STABLE STRICT
1251
    AS $_$
1252
DECLARE
1253
    value text;
1254
BEGIN
1255
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1256 8149 aaronmk
        INTO value USING key;
1257 8146 aaronmk
    RETURN value;
1258
END;
1259
$_$;
1260
1261
1262
--
1263 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1264 10325 aaronmk
--
1265
1266 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1267 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1268 10325 aaronmk
    AS $_$
1269 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1270 10325 aaronmk
$_$;
1271
1272
1273
--
1274 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1275
--
1276
1277
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].
1278
1279
[1] inlining of function calls, which is different from constant folding
1280
[2] _map()''s profiling query
1281
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1282
and map_nulls()''s profiling query
1283
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1284 10375 aaronmk
both take ~920 ms.
1285
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.';
1286 10359 aaronmk
1287
1288
--
1289 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1290 8150 aaronmk
--
1291
1292
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1293
    LANGUAGE plpgsql STABLE STRICT
1294
    AS $_$
1295
BEGIN
1296
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1297
END;
1298
$_$;
1299
1300
1301
--
1302 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1303
--
1304
1305
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1306
    LANGUAGE sql STRICT
1307
    AS $_$
1308 10135 aaronmk
SELECT util.create_if_not_exists($$
1309
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1310 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1311 10135 aaronmk
||quote_literal($2)||$$;
1312
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1313
$$)
1314 8190 aaronmk
$_$;
1315
1316
1317
--
1318
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1319
--
1320
1321
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1322
1323
1324
--
1325 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1326 8187 aaronmk
--
1327
1328 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1329 8187 aaronmk
    LANGUAGE plpgsql STRICT
1330
    AS $_$
1331
DECLARE
1332
    type regtype = util.typeof(expr, col.table_::text::regtype);
1333
    col_name_sql text = quote_ident(col.name);
1334
BEGIN
1335 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1336
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1337 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1338
$$||expr||$$;
1339
$$);
1340
END;
1341
$_$;
1342
1343
1344
--
1345 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1346 8188 aaronmk
--
1347
1348 10296 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS 'idempotent';
1349 8188 aaronmk
1350
1351
--
1352 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1353 8139 aaronmk
--
1354
1355
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1356 8141 aaronmk
    LANGUAGE sql STRICT
1357 8139 aaronmk
    AS $_$
1358 8183 aaronmk
SELECT util.create_if_not_exists($$
1359 8141 aaronmk
CREATE TABLE $$||$1||$$
1360 8139 aaronmk
(
1361 8183 aaronmk
    LIKE util.map INCLUDING ALL
1362 10110 aaronmk
);
1363
1364
CREATE TRIGGER map_filter_insert
1365
  BEFORE INSERT
1366
  ON $$||$1||$$
1367
  FOR EACH ROW
1368
  EXECUTE PROCEDURE util.map_filter_insert();
1369 8141 aaronmk
$$)
1370 8139 aaronmk
$_$;
1371
1372
1373
--
1374 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1375
--
1376
1377
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1378
    LANGUAGE sql STRICT
1379
    AS $_$
1380
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1381
$_$;
1382
1383
1384
--
1385
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1386
--
1387
1388
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1389
1390
1391
--
1392 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1393
--
1394
1395
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1396
    LANGUAGE plpgsql STRICT
1397
    AS $_$
1398 10990 aaronmk
DECLARE
1399
	view_qual_name text = util.qual_name(view_);
1400
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1401 8325 aaronmk
BEGIN
1402
	EXECUTE $$
1403 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1404
  RETURNS integer AS
1405
$BODY1$
1406
SELECT $$||quote_ident(row_num_col)||$$
1407
FROM $$||view_qual_name||$$
1408
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1409
LIMIT 1
1410
$BODY1$
1411
  LANGUAGE sql STABLE
1412
  COST 100;
1413
$$;
1414
1415
	EXECUTE $$
1416 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1417
  RETURNS SETOF $$||view_||$$ AS
1418
$BODY1$
1419 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
1420
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1421
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1422
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1423 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
1424 8325 aaronmk
$BODY1$
1425
  LANGUAGE sql STABLE
1426
  COST 100
1427
  ROWS 1000
1428
$$;
1429 8326 aaronmk
-- Also create subset function which turns off enable_sort
1430
	EXECUTE $$
1431
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1432
  RETURNS SETOF $$||view_||$$
1433
  SET enable_sort TO 'off'
1434
  AS
1435
$BODY1$
1436 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
1437 8326 aaronmk
$BODY1$
1438
  LANGUAGE sql STABLE
1439
  COST 100
1440
  ROWS 1000
1441
;
1442
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1443
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1444
If you want to run EXPLAIN and get expanded output, use the regular subset
1445
function instead. (When a config param is set on a function, EXPLAIN produces
1446
just a function scan.)
1447
';
1448
$$;
1449 8325 aaronmk
END;
1450
$_$;
1451
1452
1453
--
1454 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1455 8083 aaronmk
--
1456
1457
CREATE FUNCTION name(type regtype) RETURNS text
1458 8097 aaronmk
    LANGUAGE sql STABLE STRICT
1459 8083 aaronmk
    AS $_$
1460
SELECT typname::text FROM pg_type WHERE oid = $1
1461
$_$;
1462
1463
1464
--
1465 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1466
--
1467
1468
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1469
    LANGUAGE sql IMMUTABLE
1470
    AS $_$
1471 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1472 9958 aaronmk
$_$;
1473
1474
1475
--
1476 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1477
--
1478
1479
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1480 9957 aaronmk
    LANGUAGE sql IMMUTABLE
1481 9956 aaronmk
    AS $_$
1482
SELECT $1 IS NOT NULL
1483
$_$;
1484
1485
1486
--
1487 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1488
--
1489
1490
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1491
    LANGUAGE sql IMMUTABLE
1492
    AS $_$
1493
SELECT util.hstore($1, NULL) || '*=>*'
1494
$_$;
1495
1496
1497
--
1498
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1499
--
1500
1501
COMMENT ON FUNCTION nulls_map(nulls text[]) IS 'for use with _map()';
1502
1503
1504
--
1505 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1506 10984 aaronmk
--
1507
1508 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1509 10984 aaronmk
    LANGUAGE sql IMMUTABLE
1510
    AS $_$
1511 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
1512 10984 aaronmk
$_$;
1513
1514
1515
--
1516 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
1517
--
1518
1519
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1520
    LANGUAGE sql STABLE
1521
    AS $_$
1522
SELECT util.type_qual_name($1::text::regtype)
1523
$_$;
1524
1525
1526
--
1527 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1528
--
1529
1530
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1531
    LANGUAGE plpgsql IMMUTABLE STRICT
1532
    AS $$
1533
BEGIN
1534
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1535
END;
1536
$$;
1537
1538
1539
--
1540 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1541 8137 aaronmk
--
1542
1543 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1544 8137 aaronmk
    LANGUAGE sql STRICT
1545
    AS $_$
1546 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1547 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1548 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
1549
SELECT NULL::void; -- don't fold away functions called in previous query
1550 8137 aaronmk
$_$;
1551
1552
1553
--
1554 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1555 8137 aaronmk
--
1556
1557 8148 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1558 8137 aaronmk
1559
1560
--
1561 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1562
--
1563
1564
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1565
    LANGUAGE sql STRICT
1566
    AS $_$
1567 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
1568
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1569 10297 aaronmk
SELECT util.set_col_names($1, $2);
1570
$_$;
1571
1572
1573
--
1574
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1575
--
1576
1577
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS 'idempotent.
1578
alters the names table, so it will need to be repopulated after running this function.';
1579
1580
1581
--
1582 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1583 8143 aaronmk
--
1584
1585
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1586
    LANGUAGE sql STRICT
1587
    AS $_$
1588 10152 aaronmk
SELECT util.drop_table($1);
1589 8183 aaronmk
SELECT util.mk_map_table($1);
1590 8143 aaronmk
$_$;
1591
1592
1593
--
1594 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
1595
--
1596
1597
CREATE FUNCTION schema(type regtype) RETURNS text
1598
    LANGUAGE sql STABLE
1599
    AS $_$
1600
SELECT nspname::text
1601
FROM pg_type
1602
JOIN pg_namespace ON pg_namespace.oid = typnamespace
1603
WHERE pg_type.oid = $1
1604
$_$;
1605
1606
1607
--
1608
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1609
--
1610
1611
CREATE FUNCTION schema(type_null anyelement) RETURNS text
1612
    LANGUAGE sql STABLE
1613
    AS $_$
1614
SELECT util.schema(pg_typeof($1))
1615
$_$;
1616
1617
1618
--
1619 10795 aaronmk
-- Name: schema_ident(anyelement); Type: FUNCTION; Schema: util; Owner: -
1620
--
1621
1622
CREATE FUNCTION schema_ident(type_null anyelement) RETURNS text
1623
    LANGUAGE sql STABLE
1624
    AS $_$
1625
SELECT quote_ident(util.schema($1))
1626
$_$;
1627
1628
1629
--
1630 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1631
--
1632
1633
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1634
    LANGUAGE sql STRICT
1635
    AS $_$
1636
SELECT util.eval(
1637
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1638
$_$;
1639
1640
1641
--
1642 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1643 8153 aaronmk
--
1644
1645
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1646
    LANGUAGE plpgsql STRICT
1647
    AS $_$
1648
DECLARE
1649 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
1650
    new text[] = ARRAY(SELECT util.map_values(names));
1651 8153 aaronmk
BEGIN
1652
    old = old[1:array_length(new, 1)]; -- truncate to same length
1653 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
1654
||$$ TO $$||quote_ident(value))
1655 10149 aaronmk
    FROM each(hstore(old, new))
1656
    WHERE value != key -- not same name
1657
    ;
1658 8153 aaronmk
END;
1659
$_$;
1660
1661
1662
--
1663 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1664 8153 aaronmk
--
1665
1666
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1667
1668
1669
--
1670 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1671
--
1672
1673
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1674
    LANGUAGE plpgsql STRICT
1675
    AS $_$
1676
DECLARE
1677
	row_ util.map;
1678
BEGIN
1679 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
1680
	BEGIN
1681
		PERFORM util.set_col_names(table_, names);
1682
	EXCEPTION
1683
		WHEN array_subscript_error THEN -- selective suppress
1684
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
1685
				-- metadata cols not yet added
1686
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
1687
			END IF;
1688
	END;
1689
1690 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1691 10145 aaronmk
	LOOP
1692 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
1693
			substring(row_."from" from 2));
1694 10145 aaronmk
	END LOOP;
1695
1696
	PERFORM util.set_col_names(table_, names);
1697
END;
1698
$_$;
1699
1700
1701
--
1702
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1703
--
1704
1705
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS 'idempotent.
1706 10157 aaronmk
the metadata mappings must be *last* in the names table.';
1707 10145 aaronmk
1708
1709
--
1710 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1711 8107 aaronmk
--
1712
1713
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1714
    LANGUAGE plpgsql STRICT
1715
    AS $_$
1716
DECLARE
1717
    sql text = $$ALTER TABLE $$||table_||$$
1718
$$||NULLIF(array_to_string(ARRAY(
1719
    SELECT
1720
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1721
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1722
    FROM
1723
    (
1724
        SELECT
1725
          quote_ident(col_name) AS col_name_sql
1726 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
1727 8107 aaronmk
        , type AS target_type
1728
        FROM unnest(col_casts)
1729
    ) s
1730
    WHERE curr_type != target_type
1731
), '
1732
, '), '');
1733
BEGIN
1734
    RAISE NOTICE '%', sql;
1735
    EXECUTE COALESCE(sql, '');
1736
END;
1737
$_$;
1738
1739
1740
--
1741 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1742 8107 aaronmk
--
1743
1744
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS 'idempotent';
1745
1746
1747
--
1748 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1749 8144 aaronmk
--
1750
1751
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1752 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
1753 8144 aaronmk
    AS $_$
1754
DECLARE
1755
    hstore hstore;
1756
BEGIN
1757
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1758
        table_||$$))$$ INTO STRICT hstore;
1759
    RETURN hstore;
1760
END;
1761
$_$;
1762
1763
1764
--
1765 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1766
--
1767
1768
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
1769
    LANGUAGE sql STABLE STRICT
1770
    AS $_$
1771
SELECT COUNT(*) > 0 FROM pg_constraint
1772
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
1773
$_$;
1774
1775
1776
--
1777
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1778
--
1779
1780
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';
1781
1782
1783
--
1784 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1785
--
1786
1787
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
1788
    LANGUAGE sql STRICT
1789
    AS $_$
1790
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
1791
||quote_ident($2)||$$ CHECK (true)$$)
1792
$_$;
1793
1794
1795
--
1796
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1797
--
1798
1799
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS 'stores a status flag by the presence of a table constraint.
1800
idempotent.';
1801
1802
1803
--
1804 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
1805
--
1806
1807
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
1808
    LANGUAGE sql STABLE STRICT
1809
    AS $_$
1810
SELECT util.table_flag__get($1, 'nulls_mapped')
1811
$_$;
1812
1813
1814
--
1815
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1816
--
1817
1818
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS 'gets whether a table''s NULL-equivalent strings have been replaced with NULL';
1819
1820
1821
--
1822 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
1823
--
1824
1825
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
1826
    LANGUAGE sql STRICT
1827
    AS $_$
1828
SELECT util.table_flag__set($1, 'nulls_mapped')
1829
$_$;
1830
1831
1832
--
1833
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1834
--
1835
1836
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS 'sets that a table''s NULL-equivalent strings have been replaced with NULL.
1837
idempotent.';
1838
1839
1840
--
1841 10112 aaronmk
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1842
--
1843
1844
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1845
    LANGUAGE sql STABLE STRICT
1846
    AS $_$
1847
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1848
$_$;
1849
1850
1851
--
1852 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1853 8088 aaronmk
--
1854
1855
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1856
    LANGUAGE plpgsql STRICT
1857
    AS $_$
1858
DECLARE
1859
    row record;
1860
BEGIN
1861 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1862 8088 aaronmk
    LOOP
1863
        IF row.global_name != row.name THEN
1864
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1865
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1866
        END IF;
1867
    END LOOP;
1868
END;
1869
$_$;
1870
1871
1872
--
1873 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1874 8088 aaronmk
--
1875
1876
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1877
1878
1879
--
1880 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1881
--
1882
1883
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
1884
    LANGUAGE sql STRICT
1885
    AS $_$
1886 10595 aaronmk
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
1887 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
1888
$_$;
1889
1890
1891
--
1892
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1893
--
1894
1895 10595 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS 'trims table_ to include only columns in the original data.
1896 10365 aaronmk
idempotent.';
1897
1898
1899
--
1900 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1901 8142 aaronmk
--
1902
1903
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1904
    LANGUAGE plpgsql STRICT
1905
    AS $_$
1906
BEGIN
1907
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1908
END;
1909
$_$;
1910
1911
1912
--
1913 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1914 8142 aaronmk
--
1915
1916
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1917
1918
1919
--
1920 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1921
--
1922
1923
CREATE FUNCTION try_create(sql text) RETURNS void
1924
    LANGUAGE plpgsql STRICT
1925
    AS $$
1926
BEGIN
1927 10146 aaronmk
    PERFORM util.eval(sql);
1928 8199 aaronmk
EXCEPTION
1929 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1930 8199 aaronmk
    WHEN undefined_column THEN NULL;
1931
    WHEN duplicate_column THEN NULL;
1932
END;
1933
$$;
1934
1935
1936
--
1937
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1938
--
1939
1940
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1941
1942
1943
--
1944 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1945
--
1946
1947
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1948
    LANGUAGE sql STRICT
1949
    AS $_$
1950
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1951
$_$;
1952
1953
1954
--
1955
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1956
--
1957
1958
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1959
1960
1961
--
1962 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1963
--
1964
1965
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1966
    LANGUAGE sql IMMUTABLE
1967
    AS $_$
1968
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1969
$_$;
1970
1971
1972
--
1973 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
1974
--
1975
1976
COMMENT ON FUNCTION type_qual(value anyelement) IS 'a type''s NOT NULL qualifier';
1977
1978
1979
--
1980 8324 aaronmk
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
1981
--
1982
1983
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1984
    LANGUAGE sql STABLE STRICT
1985
    SET search_path TO pg_temp
1986
    AS $_$
1987
SELECT $1::text
1988
$_$;
1989
1990
1991
--
1992 10161 aaronmk
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
1993
--
1994
1995
COMMENT ON FUNCTION type_qual_name(type regtype) IS 'a type''s schema-qualified name';
1996
1997
1998
--
1999 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2000
--
2001
2002 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2003
    LANGUAGE plpgsql STABLE
2004 8185 aaronmk
    AS $_$
2005
DECLARE
2006
    type regtype;
2007
BEGIN
2008 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2009
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2010 8185 aaronmk
    RETURN type;
2011
END;
2012
$_$;
2013
2014
2015
--
2016 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2017
--
2018
2019
CREATE AGGREGATE all_same(anyelement) (
2020
    SFUNC = all_same_transform,
2021
    STYPE = anyarray,
2022
    FINALFUNC = all_same_final
2023
);
2024
2025
2026
--
2027
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2028
--
2029
2030
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
2031
2032
2033
--
2034 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2035 2595 aaronmk
--
2036
2037
CREATE AGGREGATE join_strs(text, text) (
2038 4052 aaronmk
    SFUNC = join_strs_transform,
2039 4010 aaronmk
    STYPE = text
2040 2595 aaronmk
);
2041
2042
2043 8147 aaronmk
--
2044 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2045 8147 aaronmk
--
2046
2047
CREATE OPERATOR -> (
2048
    PROCEDURE = map_get,
2049
    LEFTARG = regclass,
2050
    RIGHTARG = text
2051
);
2052
2053
2054 10308 aaronmk
--
2055
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2056
--
2057
2058
CREATE OPERATOR => (
2059
    PROCEDURE = hstore,
2060 10357 aaronmk
    LEFTARG = text[],
2061 10608 aaronmk
    RIGHTARG = text
2062 10308 aaronmk
);
2063
2064
2065
--
2066 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2067 10308 aaronmk
--
2068
2069 10608 aaronmk
COMMENT ON OPERATOR => (text[], text) IS 'usage: array[''key1'', ...]::text[] => ''value''';
2070 10308 aaronmk
2071
2072 10391 aaronmk
--
2073 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2074
--
2075
2076
CREATE OPERATOR ?*>= (
2077
    PROCEDURE = is_populated_more_often_than,
2078
    LEFTARG = anyelement,
2079
    RIGHTARG = anyelement
2080
);
2081
2082
2083
--
2084 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2085
--
2086
2087
CREATE OPERATOR ?>= (
2088
    PROCEDURE = is_more_complete_than,
2089
    LEFTARG = anyelement,
2090
    RIGHTARG = anyelement
2091
);
2092
2093
2094 11005 aaronmk
--
2095
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2096
--
2097
2098
CREATE OPERATOR ||% (
2099
    PROCEDURE = concat_esc,
2100
    LEFTARG = text,
2101
    RIGHTARG = text
2102
);
2103
2104
2105
--
2106
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2107
--
2108
2109
COMMENT ON OPERATOR ||% (text, text) IS '% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers';
2110
2111
2112 8140 aaronmk
SET default_tablespace = '';
2113
2114
SET default_with_oids = false;
2115
2116 2107 aaronmk
--
2117 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
2118 8140 aaronmk
--
2119
2120
CREATE TABLE map (
2121
    "from" text NOT NULL,
2122 8158 aaronmk
    "to" text,
2123
    filter text,
2124
    notes text
2125 8140 aaronmk
);
2126
2127
2128
--
2129 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2130 8140 aaronmk
--
2131
2132
2133
2134
--
2135 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
2136 8140 aaronmk
--
2137
2138
ALTER TABLE ONLY map
2139 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2140 8140 aaronmk
2141
2142
--
2143 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
2144
--
2145
2146
ALTER TABLE ONLY map
2147
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2148
2149
2150
--
2151 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2152
--
2153
2154
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2155
2156
2157
--
2158 2136 aaronmk
-- PostgreSQL database dump complete
2159
--