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 8183 aaronmk
-- Name: _join(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
225 4325 aaronmk
--
226
227
CREATE FUNCTION _join("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
228
    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 8183 aaronmk
-- Name: _join_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
236 5009 aaronmk
--
237
238
CREATE FUNCTION _join_words("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
239
    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 8183 aaronmk
-- Name: _label(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
247 3422 aaronmk
--
248
249 4683 aaronmk
CREATE FUNCTION _label(label anyelement, value anyelement) RETURNS anyelement
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 9959 aaronmk
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
528
--
529
530
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
531
    LANGUAGE sql IMMUTABLE
532
    AS $_$
533
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
534
$_$;
535
536
537
--
538
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
539
--
540
541
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
542
    LANGUAGE plpgsql IMMUTABLE
543
    AS $$
544
DECLARE
545
	value_cmp         state%TYPE = ARRAY[value];
546
	state             state%TYPE = COALESCE(state, value_cmp);
547
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
548
BEGIN
549
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
550
END;
551
$$;
552
553
554
--
555 10305 aaronmk
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
556
--
557
558
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
559
    LANGUAGE sql IMMUTABLE
560
    AS $_$
561
SELECT pg_catalog.array_fill($1, ARRAY[$2])
562
$_$;
563
564
565
--
566 10303 aaronmk
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
567
--
568
569
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
570 10354 aaronmk
    LANGUAGE sql IMMUTABLE
571 10303 aaronmk
    AS $_$
572 10321 aaronmk
SELECT util.array_length($1, 1)
573 10303 aaronmk
$_$;
574
575
576
--
577 10304 aaronmk
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
578
--
579
580
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
581 10354 aaronmk
    LANGUAGE sql IMMUTABLE
582 10304 aaronmk
    AS $_$
583 10354 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
584 10304 aaronmk
$_$;
585
586
587
--
588
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
589
--
590
591
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS 'returns 0 instead of NULL for empty arrays';
592
593
594
--
595 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
596 8104 aaronmk
--
597
598
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
599
    LANGUAGE sql STABLE STRICT
600
    AS $_$
601
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
602
$_$;
603
604
605
--
606 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
607 8105 aaronmk
--
608
609
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
610
    LANGUAGE plpgsql STRICT
611
    AS $_$
612
BEGIN
613
    -- not yet clustered (ARRAY[] compares NULLs literally)
614 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
615 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
616
    END IF;
617
END;
618
$_$;
619
620
621
--
622 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
623 8105 aaronmk
--
624
625
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
626
627
628
--
629 10136 aaronmk
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
630
--
631
632
CREATE FUNCTION col_comment(col col_ref) RETURNS text
633
    LANGUAGE plpgsql STABLE STRICT
634
    AS $$
635
DECLARE
636
	comment text;
637
BEGIN
638
	SELECT description
639
	FROM pg_attribute
640
	LEFT JOIN pg_description ON objoid = attrelid
641
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
642
	WHERE attrelid = col.table_ AND attname = col.name
643
	INTO STRICT comment
644
	;
645
	RETURN comment;
646
EXCEPTION
647
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
648
END;
649
$$;
650
651
652
--
653 10130 aaronmk
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
654
--
655
656
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
657
    LANGUAGE plpgsql STABLE STRICT
658
    AS $$
659
DECLARE
660
	default_sql text;
661
BEGIN
662
	SELECT adsrc
663
	FROM pg_attribute
664
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
665
	WHERE attrelid = col.table_ AND attname = col.name
666
	INTO STRICT default_sql
667
	;
668
	RETURN default_sql;
669
EXCEPTION
670
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
671
END;
672
$$;
673
674
675
--
676 10134 aaronmk
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
677
--
678
679
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
680
    LANGUAGE sql STABLE
681
    AS $_$
682
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
683
$_$;
684
685
686
--
687
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
688
--
689
690
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
691
692
693
--
694 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
695 8180 aaronmk
--
696
697
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
698
    LANGUAGE plpgsql STRICT
699
    AS $$
700
BEGIN
701 8183 aaronmk
    PERFORM util.col_type(col);
702 8180 aaronmk
    RETURN true;
703
EXCEPTION
704
    WHEN undefined_column THEN RETURN false;
705
END;
706
$$;
707
708
709
--
710 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
711 8084 aaronmk
--
712
713
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
714 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
715 8084 aaronmk
    AS $$
716
DECLARE
717 8183 aaronmk
    prefix text := util.name(type)||'.';
718 8084 aaronmk
BEGIN
719
    RETURN QUERY
720 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
721
        FROM util.col_names(type) f (name_);
722 8084 aaronmk
END;
723
$$;
724
725
726
--
727 8183 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
728 8082 aaronmk
--
729
730
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
731 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
732 8082 aaronmk
    AS $_$
733
BEGIN
734
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
735
END;
736
$_$;
737
738
739
--
740 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
741 8151 aaronmk
--
742
743
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
744
    LANGUAGE sql STABLE STRICT
745
    AS $_$
746
SELECT attname::text
747
FROM pg_attribute
748 10158 aaronmk
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
749 8151 aaronmk
ORDER BY attnum
750
$_$;
751
752
753
--
754 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
755 8106 aaronmk
--
756
757
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
758 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
759
    AS $$
760
DECLARE
761
    type regtype;
762
BEGIN
763
    SELECT atttypid FROM pg_attribute
764
    WHERE attrelid = col.table_ AND attname = col.name
765
    INTO STRICT type
766
    ;
767
    RETURN type;
768
EXCEPTION
769 8171 aaronmk
    WHEN no_data_found THEN
770 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
771
            concat('undefined column: ', col.name);
772 8169 aaronmk
END;
773
$$;
774 8106 aaronmk
775
776
--
777 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
778 8095 aaronmk
--
779
780
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
781 10388 aaronmk
    LANGUAGE sql IMMUTABLE
782 8095 aaronmk
    AS $_$
783
SELECT position($1 in $2) > 0 /*1-based offset*/
784
$_$;
785
786
787
--
788 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
789 8094 aaronmk
--
790
791
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
792
    LANGUAGE plpgsql STRICT
793
    AS $$
794
BEGIN
795 10146 aaronmk
    PERFORM util.eval(sql);
796 8094 aaronmk
EXCEPTION
797 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
798 10181 aaronmk
    WHEN duplicate_object THEN NULL; -- e.g. constraint
799 8103 aaronmk
    WHEN duplicate_column THEN NULL;
800 10244 aaronmk
    WHEN invalid_table_definition THEN
801
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
802
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
803
        END IF;
804 8094 aaronmk
END;
805
$$;
806
807
808
--
809 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
810 8094 aaronmk
--
811
812
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
813
814
815
--
816 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
817
--
818
819
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
820
    LANGUAGE sql STABLE STRICT
821
    AS $_$
822
SELECT util.eval2set($$
823
SELECT col
824
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
825
LEFT JOIN $$||$2||$$ ON "to" = col
826
WHERE "from" IS NULL
827
$$, NULL::text)
828
$_$;
829
830
831
--
832
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
833
--
834
835
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS 'gets table_''s derived columns (all the columns not in the names table)';
836
837
838
--
839 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
840
--
841
842
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
843
    LANGUAGE sql STRICT
844
    AS $_$
845
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
846
$_$;
847
848
849
--
850
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
851
--
852
853
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
854
855
856
--
857 10362 aaronmk
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
858
--
859
860
CREATE FUNCTION drop_column(col col_ref) RETURNS void
861
    LANGUAGE sql STRICT
862
    AS $_$
863
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
864
quote_ident($1.name))
865
$_$;
866
867
868
--
869
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
870
--
871
872
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
873
874
875
--
876 10150 aaronmk
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
877
--
878
879
CREATE FUNCTION drop_table(table_ text) RETURNS void
880
    LANGUAGE sql STRICT
881
    AS $_$
882
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
883
$_$;
884
885
886
--
887
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
888
--
889
890
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
891
892
893
--
894 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
895
--
896
897
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
898
    LANGUAGE sql IMMUTABLE
899
    AS $_$
900
SELECT util.array_fill($1, 0)
901
$_$;
902
903
904
--
905
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
906
--
907
908
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)';
909
910
911
--
912 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
913 8086 aaronmk
--
914
915
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
916 10388 aaronmk
    LANGUAGE sql IMMUTABLE
917 8086 aaronmk
    AS $_$
918 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
919 8086 aaronmk
$_$;
920
921
922
--
923 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
924
--
925
926
CREATE FUNCTION eval(sql text) RETURNS void
927
    LANGUAGE plpgsql STRICT
928
    AS $$
929
BEGIN
930
    RAISE NOTICE '%', sql;
931
    EXECUTE sql;
932
END;
933
$$;
934
935
936
--
937 10363 aaronmk
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
938
--
939
940
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
941
    LANGUAGE plpgsql
942
    AS $$
943
BEGIN
944
	RAISE NOTICE '%', sql;
945
	RETURN QUERY EXECUTE sql;
946
END;
947
$$;
948
949
950
--
951
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
952
--
953
954
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
955
956
957
--
958 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
959 10128 aaronmk
--
960
961 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
962 10128 aaronmk
    LANGUAGE plpgsql
963
    AS $$
964
DECLARE
965
	ret_val ret_type_null%TYPE;
966
BEGIN
967
	RAISE NOTICE '%', sql;
968
	EXECUTE sql INTO STRICT ret_val;
969
	RETURN ret_val;
970
END;
971
$$;
972
973
974
--
975 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
976 10128 aaronmk
--
977
978 10129 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
979 10128 aaronmk
980
981
--
982 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
983
--
984
985
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
986
    LANGUAGE sql
987
    AS $_$
988 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
989 10131 aaronmk
$_$;
990
991
992
--
993
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
994
--
995
996
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
997
998
999
--
1000 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1001
--
1002
1003
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1004
    LANGUAGE sql
1005
    AS $_$
1006
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1007
$_$;
1008
1009
1010
--
1011
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1012
--
1013
1014
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1015
ret_type_null: NULL::ret_type';
1016
1017
1018
--
1019 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1020 8182 aaronmk
--
1021
1022
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1023
    LANGUAGE sql STABLE STRICT
1024
    AS $_$
1025
SELECT col_name
1026
FROM unnest($2) s (col_name)
1027 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1028 8182 aaronmk
$_$;
1029
1030
1031
--
1032 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1033
--
1034
1035
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1036 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1037 10323 aaronmk
    AS $_$
1038
-- STRICT handles NULLs, so that the array will always be a value
1039 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1040
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1041
) END
1042 10323 aaronmk
$_$;
1043
1044
1045
--
1046
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1047
--
1048
1049
COMMENT ON FUNCTION fix_array("array" anyarray) IS 'ensures that an array will always have proper non-NULL dimensions';
1050
1051
1052
--
1053 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1054
--
1055
1056
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1057
    LANGUAGE plpgsql STRICT
1058
    AS $_$
1059
DECLARE
1060
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1061
$$||query;
1062
BEGIN
1063
	EXECUTE mk_view;
1064
EXCEPTION
1065
WHEN invalid_table_definition THEN
1066 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1067
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1068
	THEN
1069 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1070
		EXECUTE mk_view;
1071
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1072
	END IF;
1073
END;
1074
$_$;
1075
1076
1077
--
1078
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1079
--
1080
1081
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1082
1083
1084
--
1085 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1086 8085 aaronmk
--
1087
1088
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1089 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1090 8085 aaronmk
    AS $_$
1091
SELECT substring($2 for length($1)) = $1
1092
$_$;
1093
1094
1095
--
1096 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1097
--
1098
1099
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1100
    LANGUAGE sql IMMUTABLE
1101
    AS $_$
1102 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1103 10307 aaronmk
$_$;
1104
1105
1106
--
1107
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1108
--
1109
1110
COMMENT ON FUNCTION hstore(keys text[], value text) IS 'avoids repeating the same value for each key';
1111
1112
1113
--
1114 10356 aaronmk
-- Name: hstore(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1115
--
1116
1117
CREATE FUNCTION hstore(keys text[], value anyelement) RETURNS hstore
1118
    LANGUAGE sql IMMUTABLE
1119
    AS $_$
1120
SELECT util.hstore($1, $2::text)
1121
$_$;
1122
1123
1124
--
1125
-- Name: FUNCTION hstore(keys text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1126
--
1127
1128
COMMENT ON FUNCTION hstore(keys text[], value anyelement) IS 'avoids repeating the same value for each key';
1129
1130
1131
--
1132 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1133
--
1134
1135
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1136
    LANGUAGE sql STABLE STRICT
1137
    AS $_$
1138
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1139
$_$;
1140
1141
1142
--
1143 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1144
--
1145
1146
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1147
    LANGUAGE sql IMMUTABLE
1148
    AS $_$
1149
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1150
$_$;
1151
1152
1153
--
1154 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1155 4009 aaronmk
--
1156
1157 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1158 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1159 4009 aaronmk
    AS $_$
1160 4054 aaronmk
SELECT $1 || $3 || $2
1161 2595 aaronmk
$_$;
1162
1163
1164
--
1165 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1166
--
1167
1168
CREATE FUNCTION map_filter_insert() RETURNS trigger
1169
    LANGUAGE plpgsql
1170
    AS $$
1171
BEGIN
1172
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1173
	RETURN new;
1174
END;
1175
$$;
1176
1177
1178
--
1179 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1180 8146 aaronmk
--
1181
1182
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1183
    LANGUAGE plpgsql STABLE STRICT
1184
    AS $_$
1185
DECLARE
1186
    value text;
1187
BEGIN
1188
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1189 8149 aaronmk
        INTO value USING key;
1190 8146 aaronmk
    RETURN value;
1191
END;
1192
$_$;
1193
1194
1195
--
1196 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1197 10325 aaronmk
--
1198
1199 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1200 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1201 10325 aaronmk
    AS $_$
1202 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1203 10325 aaronmk
$_$;
1204
1205
1206
--
1207 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1208
--
1209
1210
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].
1211
1212
[1] inlining of function calls, which is different from constant folding
1213
[2] _map()''s profiling query
1214
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1215
and map_nulls()''s profiling query
1216
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1217 10375 aaronmk
both take ~920 ms.
1218
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.';
1219 10359 aaronmk
1220
1221
--
1222 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1223 8150 aaronmk
--
1224
1225
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1226
    LANGUAGE plpgsql STABLE STRICT
1227
    AS $_$
1228
BEGIN
1229
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1230
END;
1231
$_$;
1232
1233
1234
--
1235 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1236
--
1237
1238
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1239
    LANGUAGE sql STRICT
1240
    AS $_$
1241 10135 aaronmk
SELECT util.create_if_not_exists($$
1242
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1243 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1244 10135 aaronmk
||quote_literal($2)||$$;
1245
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1246
$$)
1247 8190 aaronmk
$_$;
1248
1249
1250
--
1251
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1252
--
1253
1254
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1255
1256
1257
--
1258 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1259 8187 aaronmk
--
1260
1261 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1262 8187 aaronmk
    LANGUAGE plpgsql STRICT
1263
    AS $_$
1264
DECLARE
1265
    type regtype = util.typeof(expr, col.table_::text::regtype);
1266
    col_name_sql text = quote_ident(col.name);
1267
BEGIN
1268 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1269
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1270 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1271
$$||expr||$$;
1272
$$);
1273
END;
1274
$_$;
1275
1276
1277
--
1278 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1279 8188 aaronmk
--
1280
1281 10296 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS 'idempotent';
1282 8188 aaronmk
1283
1284
--
1285 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1286 8139 aaronmk
--
1287
1288
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1289 8141 aaronmk
    LANGUAGE sql STRICT
1290 8139 aaronmk
    AS $_$
1291 8183 aaronmk
SELECT util.create_if_not_exists($$
1292 8141 aaronmk
CREATE TABLE $$||$1||$$
1293 8139 aaronmk
(
1294 8183 aaronmk
    LIKE util.map INCLUDING ALL
1295 10110 aaronmk
);
1296
1297
CREATE TRIGGER map_filter_insert
1298
  BEFORE INSERT
1299
  ON $$||$1||$$
1300
  FOR EACH ROW
1301
  EXECUTE PROCEDURE util.map_filter_insert();
1302 8141 aaronmk
$$)
1303 8139 aaronmk
$_$;
1304
1305
1306
--
1307 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1308
--
1309
1310
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1311
    LANGUAGE sql STRICT
1312
    AS $_$
1313
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1314
$_$;
1315
1316
1317
--
1318
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1319
--
1320
1321
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1322
1323
1324
--
1325 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1326
--
1327
1328
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1329
    LANGUAGE plpgsql STRICT
1330
    AS $_$
1331
BEGIN
1332
	EXECUTE $$
1333
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1334
  RETURNS SETOF $$||view_||$$ AS
1335
$BODY1$
1336
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$
1337 8331 aaronmk
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN COALESCE($2, 0)+1 AND COALESCE(COALESCE($2, 0)+1 + $1 - 1, 2147483647)
1338 8325 aaronmk
$BODY1$
1339
  LANGUAGE sql STABLE
1340
  COST 100
1341
  ROWS 1000
1342
$$;
1343 8326 aaronmk
-- Also create subset function which turns off enable_sort
1344
	EXECUTE $$
1345
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1346
  RETURNS SETOF $$||view_||$$
1347
  SET enable_sort TO 'off'
1348
  AS
1349
$BODY1$
1350 8328 aaronmk
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$($2, $3)
1351 8326 aaronmk
$BODY1$
1352
  LANGUAGE sql STABLE
1353
  COST 100
1354
  ROWS 1000
1355
;
1356
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1357
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1358
If you want to run EXPLAIN and get expanded output, use the regular subset
1359
function instead. (When a config param is set on a function, EXPLAIN produces
1360
just a function scan.)
1361
';
1362
$$;
1363 8325 aaronmk
END;
1364
$_$;
1365
1366
1367
--
1368 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1369 8083 aaronmk
--
1370
1371
CREATE FUNCTION name(type regtype) RETURNS text
1372 8097 aaronmk
    LANGUAGE sql STABLE STRICT
1373 8083 aaronmk
    AS $_$
1374
SELECT typname::text FROM pg_type WHERE oid = $1
1375
$_$;
1376
1377
1378
--
1379 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1380
--
1381
1382
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1383
    LANGUAGE sql IMMUTABLE
1384
    AS $_$
1385 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1386 9958 aaronmk
$_$;
1387
1388
1389
--
1390 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1391
--
1392
1393
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1394 9957 aaronmk
    LANGUAGE sql IMMUTABLE
1395 9956 aaronmk
    AS $_$
1396
SELECT $1 IS NOT NULL
1397
$_$;
1398
1399
1400
--
1401 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1402
--
1403
1404
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1405
    LANGUAGE sql IMMUTABLE
1406
    AS $_$
1407
SELECT util.hstore($1, NULL) || '*=>*'
1408
$_$;
1409
1410
1411
--
1412
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1413
--
1414
1415
COMMENT ON FUNCTION nulls_map(nulls text[]) IS 'for use with _map()';
1416
1417
1418
--
1419 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1420
--
1421
1422
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1423
    LANGUAGE plpgsql IMMUTABLE STRICT
1424
    AS $$
1425
BEGIN
1426
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1427
END;
1428
$$;
1429
1430
1431
--
1432 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1433 8137 aaronmk
--
1434
1435 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1436 8137 aaronmk
    LANGUAGE sql STRICT
1437
    AS $_$
1438 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1439 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1440 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
1441
SELECT NULL::void; -- don't fold away functions called in previous query
1442 8137 aaronmk
$_$;
1443
1444
1445
--
1446 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1447 8137 aaronmk
--
1448
1449 8148 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1450 8137 aaronmk
1451
1452
--
1453 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1454
--
1455
1456
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1457
    LANGUAGE sql STRICT
1458
    AS $_$
1459
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1460
SELECT util.set_col_names($1, $2);
1461
$_$;
1462
1463
1464
--
1465
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1466
--
1467
1468
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS 'idempotent.
1469
alters the names table, so it will need to be repopulated after running this function.';
1470
1471
1472
--
1473 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1474 8143 aaronmk
--
1475
1476
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1477
    LANGUAGE sql STRICT
1478
    AS $_$
1479 10152 aaronmk
SELECT util.drop_table($1);
1480 8183 aaronmk
SELECT util.mk_map_table($1);
1481 8143 aaronmk
$_$;
1482
1483
1484
--
1485 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1486
--
1487
1488
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1489
    LANGUAGE sql STRICT
1490
    AS $_$
1491
SELECT util.eval(
1492
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1493
$_$;
1494
1495
1496
--
1497 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1498 8153 aaronmk
--
1499
1500
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1501
    LANGUAGE plpgsql STRICT
1502
    AS $_$
1503
DECLARE
1504 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
1505
    new text[] = ARRAY(SELECT util.map_values(names));
1506 8153 aaronmk
BEGIN
1507
    old = old[1:array_length(new, 1)]; -- truncate to same length
1508 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
1509
||$$ TO $$||quote_ident(value))
1510 10149 aaronmk
    FROM each(hstore(old, new))
1511
    WHERE value != key -- not same name
1512
    ;
1513 8153 aaronmk
END;
1514
$_$;
1515
1516
1517
--
1518 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1519 8153 aaronmk
--
1520
1521
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1522
1523
1524
--
1525 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1526
--
1527
1528
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1529
    LANGUAGE plpgsql STRICT
1530
    AS $_$
1531
DECLARE
1532
	row_ util.map;
1533
BEGIN
1534 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1535 10145 aaronmk
	LOOP
1536 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
1537
			substring(row_."from" from 2));
1538 10145 aaronmk
	END LOOP;
1539
1540
	PERFORM util.set_col_names(table_, names);
1541
END;
1542
$_$;
1543
1544
1545
--
1546
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1547
--
1548
1549
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS 'idempotent.
1550 10157 aaronmk
the metadata mappings must be *last* in the names table.';
1551 10145 aaronmk
1552
1553
--
1554 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1555 8107 aaronmk
--
1556
1557
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1558
    LANGUAGE plpgsql STRICT
1559
    AS $_$
1560
DECLARE
1561
    sql text = $$ALTER TABLE $$||table_||$$
1562
$$||NULLIF(array_to_string(ARRAY(
1563
    SELECT
1564
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1565
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1566
    FROM
1567
    (
1568
        SELECT
1569
          quote_ident(col_name) AS col_name_sql
1570 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
1571 8107 aaronmk
        , type AS target_type
1572
        FROM unnest(col_casts)
1573
    ) s
1574
    WHERE curr_type != target_type
1575
), '
1576
, '), '');
1577
BEGIN
1578
    RAISE NOTICE '%', sql;
1579
    EXECUTE COALESCE(sql, '');
1580
END;
1581
$_$;
1582
1583
1584
--
1585 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1586 8107 aaronmk
--
1587
1588
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS 'idempotent';
1589
1590
1591
--
1592 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1593 8144 aaronmk
--
1594
1595
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1596 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
1597 8144 aaronmk
    AS $_$
1598
DECLARE
1599
    hstore hstore;
1600
BEGIN
1601
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1602
        table_||$$))$$ INTO STRICT hstore;
1603
    RETURN hstore;
1604
END;
1605
$_$;
1606
1607
1608
--
1609 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1610
--
1611
1612
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
1613
    LANGUAGE sql STABLE STRICT
1614
    AS $_$
1615
SELECT COUNT(*) > 0 FROM pg_constraint
1616
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
1617
$_$;
1618
1619
1620
--
1621
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1622
--
1623
1624
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';
1625
1626
1627
--
1628 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1629
--
1630
1631
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
1632
    LANGUAGE sql STRICT
1633
    AS $_$
1634
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
1635
||quote_ident($2)||$$ CHECK (true)$$)
1636
$_$;
1637
1638
1639
--
1640
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
1641
--
1642
1643
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS 'stores a status flag by the presence of a table constraint.
1644
idempotent.';
1645
1646
1647
--
1648 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
1649
--
1650
1651
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
1652
    LANGUAGE sql STABLE STRICT
1653
    AS $_$
1654
SELECT util.table_flag__get($1, 'nulls_mapped')
1655
$_$;
1656
1657
1658
--
1659
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1660
--
1661
1662
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS 'gets whether a table''s NULL-equivalent strings have been replaced with NULL';
1663
1664
1665
--
1666 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
1667
--
1668
1669
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
1670
    LANGUAGE sql STRICT
1671
    AS $_$
1672
SELECT util.table_flag__set($1, 'nulls_mapped')
1673
$_$;
1674
1675
1676
--
1677
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1678
--
1679
1680
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS 'sets that a table''s NULL-equivalent strings have been replaced with NULL.
1681
idempotent.';
1682
1683
1684
--
1685 10112 aaronmk
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1686
--
1687
1688
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1689
    LANGUAGE sql STABLE STRICT
1690
    AS $_$
1691
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1692
$_$;
1693
1694
1695
--
1696 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1697 8088 aaronmk
--
1698
1699
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1700
    LANGUAGE plpgsql STRICT
1701
    AS $_$
1702
DECLARE
1703
    row record;
1704
BEGIN
1705 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1706 8088 aaronmk
    LOOP
1707
        IF row.global_name != row.name THEN
1708
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1709
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1710
        END IF;
1711
    END LOOP;
1712
END;
1713
$_$;
1714
1715
1716
--
1717 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1718 8088 aaronmk
--
1719
1720
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1721
1722
1723
--
1724 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1725
--
1726
1727
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
1728
    LANGUAGE sql STRICT
1729
    AS $_$
1730
SELECT util.drop_column(($1, col)) FROM util.derived_cols($1, $2) f (col);
1731
SELECT NULL::void; -- don't fold away functions called in previous query
1732
$_$;
1733
1734
1735
--
1736
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1737
--
1738
1739
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS 'trims table_ to include only original columns, as defined by the names table.
1740
idempotent.';
1741
1742
1743
--
1744 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1745 8142 aaronmk
--
1746
1747
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1748
    LANGUAGE plpgsql STRICT
1749
    AS $_$
1750
BEGIN
1751
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1752
END;
1753
$_$;
1754
1755
1756
--
1757 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1758 8142 aaronmk
--
1759
1760
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1761
1762
1763
--
1764 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1765
--
1766
1767
CREATE FUNCTION try_create(sql text) RETURNS void
1768
    LANGUAGE plpgsql STRICT
1769
    AS $$
1770
BEGIN
1771 10146 aaronmk
    PERFORM util.eval(sql);
1772 8199 aaronmk
EXCEPTION
1773 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1774 8199 aaronmk
    WHEN undefined_column THEN NULL;
1775
    WHEN duplicate_column THEN NULL;
1776
END;
1777
$$;
1778
1779
1780
--
1781
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1782
--
1783
1784
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1785
1786
1787
--
1788 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1789
--
1790
1791
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1792
    LANGUAGE sql STRICT
1793
    AS $_$
1794
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1795
$_$;
1796
1797
1798
--
1799
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1800
--
1801
1802
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1803
1804
1805
--
1806 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1807
--
1808
1809
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1810
    LANGUAGE sql IMMUTABLE
1811
    AS $_$
1812
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1813
$_$;
1814
1815
1816
--
1817 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
1818
--
1819
1820
COMMENT ON FUNCTION type_qual(value anyelement) IS 'a type''s NOT NULL qualifier';
1821
1822
1823
--
1824 8324 aaronmk
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
1825
--
1826
1827
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1828
    LANGUAGE sql STABLE STRICT
1829
    SET search_path TO pg_temp
1830
    AS $_$
1831
SELECT $1::text
1832
$_$;
1833
1834
1835
--
1836 10161 aaronmk
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
1837
--
1838
1839
COMMENT ON FUNCTION type_qual_name(type regtype) IS 'a type''s schema-qualified name';
1840
1841
1842
--
1843 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
1844
--
1845
1846 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
1847
    LANGUAGE plpgsql STABLE
1848 8185 aaronmk
    AS $_$
1849
DECLARE
1850
    type regtype;
1851
BEGIN
1852 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
1853
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
1854 8185 aaronmk
    RETURN type;
1855
END;
1856
$_$;
1857
1858
1859
--
1860 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
1861
--
1862
1863
CREATE AGGREGATE all_same(anyelement) (
1864
    SFUNC = all_same_transform,
1865
    STYPE = anyarray,
1866
    FINALFUNC = all_same_final
1867
);
1868
1869
1870
--
1871
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
1872
--
1873
1874
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
1875
1876
1877
--
1878 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1879 2595 aaronmk
--
1880
1881
CREATE AGGREGATE join_strs(text, text) (
1882 4052 aaronmk
    SFUNC = join_strs_transform,
1883 4010 aaronmk
    STYPE = text
1884 2595 aaronmk
);
1885
1886
1887 8147 aaronmk
--
1888 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1889 8147 aaronmk
--
1890
1891
CREATE OPERATOR -> (
1892
    PROCEDURE = map_get,
1893
    LEFTARG = regclass,
1894
    RIGHTARG = text
1895
);
1896
1897
1898 10308 aaronmk
--
1899
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
1900
--
1901
1902
CREATE OPERATOR => (
1903
    PROCEDURE = hstore,
1904 10357 aaronmk
    LEFTARG = text[],
1905 10327 aaronmk
    RIGHTARG = anyelement
1906 10308 aaronmk
);
1907
1908
1909
--
1910 10357 aaronmk
-- Name: OPERATOR => (text[], anyelement); Type: COMMENT; Schema: util; Owner: -
1911 10308 aaronmk
--
1912
1913 10357 aaronmk
COMMENT ON OPERATOR => (text[], anyelement) IS 'usage: array[''key1'', ...]::text[] => ''value''';
1914 10308 aaronmk
1915
1916 10391 aaronmk
--
1917
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
1918
--
1919
1920
CREATE OPERATOR ?>= (
1921
    PROCEDURE = is_more_complete_than,
1922
    LEFTARG = anyelement,
1923
    RIGHTARG = anyelement
1924
);
1925
1926
1927 8140 aaronmk
SET default_tablespace = '';
1928
1929
SET default_with_oids = false;
1930
1931 2107 aaronmk
--
1932 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
1933 8140 aaronmk
--
1934
1935
CREATE TABLE map (
1936
    "from" text NOT NULL,
1937 8158 aaronmk
    "to" text,
1938
    filter text,
1939
    notes text
1940 8140 aaronmk
);
1941
1942
1943
--
1944 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
1945 8140 aaronmk
--
1946
1947
1948
1949
--
1950 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
1951 8140 aaronmk
--
1952
1953
ALTER TABLE ONLY map
1954 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
1955 8140 aaronmk
1956
1957
--
1958 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
1959
--
1960
1961
ALTER TABLE ONLY map
1962
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
1963
1964
1965
--
1966 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
1967
--
1968
1969
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
1970
1971
1972
--
1973 2136 aaronmk
-- PostgreSQL database dump complete
1974
--