Project

General

Profile

1 2094 aaronmk
--
2
-- PostgreSQL database dump
3
--
4
5
SET statement_timeout = 0;
6
SET client_encoding = 'UTF8';
7 6213 aaronmk
SET standard_conforming_strings = on;
8 2094 aaronmk
SET check_function_bodies = false;
9
SET client_min_messages = warning;
10
11
--
12 8183 aaronmk
-- Name: util; Type: SCHEMA; Schema: -; Owner: -
13 2094 aaronmk
--
14
15 8183 aaronmk
CREATE SCHEMA util;
16 2094 aaronmk
17
18 4982 aaronmk
--
19 8183 aaronmk
-- Name: SCHEMA util; Type: COMMENT; Schema: -; Owner: -
20 4982 aaronmk
--
21
22 8183 aaronmk
COMMENT ON SCHEMA util IS 'IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.';
23 4982 aaronmk
24
25 8183 aaronmk
SET search_path = util, pg_catalog;
26 2107 aaronmk
27 2094 aaronmk
--
28 8183 aaronmk
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
29 8107 aaronmk
--
30
31
CREATE TYPE col_cast AS (
32
	col_name text,
33
	type regtype
34
);
35
36
37
--
38 8183 aaronmk
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
39 8106 aaronmk
--
40
41
CREATE TYPE col_ref AS (
42
	table_ regclass,
43
	name text
44
);
45
46
47
--
48 8183 aaronmk
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
49 7673 aaronmk
--
50
51
CREATE TYPE compass_dir AS ENUM (
52
    'N',
53
    'E',
54
    'S',
55
    'W'
56
);
57
58
59
--
60 8183 aaronmk
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
61 2610 aaronmk
--
62
63
CREATE TYPE datatype AS ENUM (
64
    'str',
65
    'float'
66
);
67
68
69
--
70 8183 aaronmk
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
71 2596 aaronmk
--
72
73 4501 aaronmk
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
74 3422 aaronmk
    LANGUAGE sql IMMUTABLE
75
    AS $_$
76 4501 aaronmk
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
77 3422 aaronmk
$_$;
78
79
80
--
81 8183 aaronmk
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
82 5937 aaronmk
--
83
84 5956 aaronmk
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
85 5937 aaronmk
    LANGUAGE sql IMMUTABLE
86
    AS $_$
87
SELECT bool_and(value)
88
FROM
89
(VALUES
90
      ($1)
91
    , ($2)
92 5956 aaronmk
    , ($3)
93
    , ($4)
94
    , ($5)
95 5937 aaronmk
)
96
AS v (value)
97
$_$;
98
99
100
--
101 8183 aaronmk
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
102 5937 aaronmk
--
103
104 6437 aaronmk
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.';
105 5937 aaronmk
106
107
--
108 8183 aaronmk
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
109 7704 aaronmk
--
110
111
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
112
    LANGUAGE sql IMMUTABLE
113
    AS $_$
114
SELECT avg(value)
115
FROM
116
(VALUES
117
      ($1)
118
    , ($2)
119
    , ($3)
120
    , ($4)
121
    , ($5)
122
)
123
AS v (value)
124
$_$;
125
126
127
--
128 8183 aaronmk
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
129 7679 aaronmk
--
130
131
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
132
    LANGUAGE sql IMMUTABLE STRICT
133
    AS $_$
134 8183 aaronmk
SELECT (g[1]||'1')::integer*util._dms_to_dd(deg := g[2]::double precision, min := g[3]::double precision, sec := g[4]::double precision, dir := g[5]::util.compass_dir)
135 7698 aaronmk
FROM
136
(
137
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
138
    UNION ALL
139 7702 aaronmk
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
140
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
141 7698 aaronmk
)
142
matches (g)
143 7679 aaronmk
$_$;
144
145
146
--
147 8183 aaronmk
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
148 7672 aaronmk
--
149
150 7674 aaronmk
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
151 7672 aaronmk
    LANGUAGE sql IMMUTABLE
152
    AS $_$
153 8183 aaronmk
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
154 7672 aaronmk
FROM
155
(VALUES
156 7677 aaronmk
      ($1)
157 7672 aaronmk
    , ($2/60)
158
    , ($3/60/60)
159
)
160
AS v (value)
161
$_$;
162
163
164
--
165 8183 aaronmk
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
166 7723 aaronmk
--
167
168
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
169
    LANGUAGE sql IMMUTABLE
170
    AS $_$
171 8183 aaronmk
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
172 7723 aaronmk
$_$;
173
174
175
--
176 8183 aaronmk
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
177 4142 aaronmk
--
178
179
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
180
    LANGUAGE sql IMMUTABLE
181
    AS $_$
182
SELECT $1 = $2
183
$_$;
184
185
186
--
187 8183 aaronmk
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
188 7396 aaronmk
--
189
190
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
191
    LANGUAGE sql IMMUTABLE
192
    AS $_$
193
-- Fix dates after threshold date
194
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
195
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
196
$_$;
197
198
199
--
200 8183 aaronmk
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
201 4147 aaronmk
--
202
203
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
204
    LANGUAGE sql IMMUTABLE
205
    AS $_$
206
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
207
$_$;
208
209
210
--
211 8183 aaronmk
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
212 4147 aaronmk
--
213
214
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
215
    LANGUAGE sql IMMUTABLE
216
    AS $_$
217 8183 aaronmk
SELECT util._if($1 != '', $2, $3)
218 4147 aaronmk
$_$;
219
220
221
--
222 8183 aaronmk
-- Name: _join(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
223 4325 aaronmk
--
224
225
CREATE FUNCTION _join("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
226
    LANGUAGE sql IMMUTABLE
227
    AS $_$
228 7848 aaronmk
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
229 4325 aaronmk
$_$;
230
231
232
--
233 8183 aaronmk
-- Name: _join_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
234 5009 aaronmk
--
235
236
CREATE FUNCTION _join_words("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
237
    LANGUAGE sql IMMUTABLE
238
    AS $_$
239 7848 aaronmk
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
240 5009 aaronmk
$_$;
241
242
243
--
244 8183 aaronmk
-- Name: _label(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
245 3422 aaronmk
--
246
247 4683 aaronmk
CREATE FUNCTION _label(label anyelement, value anyelement) RETURNS anyelement
248 4682 aaronmk
    LANGUAGE sql IMMUTABLE
249
    AS $_$
250
SELECT coalesce($1 || ': ', '') || $2
251
$_$;
252 2596 aaronmk
253
254
--
255 8825 aaronmk
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
256
--
257
258
CREATE FUNCTION _lowercase(value text) RETURNS text
259
    LANGUAGE sql IMMUTABLE STRICT
260
    AS $_$
261
SELECT lower($1)
262
$_$;
263
264
265
--
266 8183 aaronmk
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
267 6222 aaronmk
--
268
269
CREATE FUNCTION _map(map hstore, value text) RETURNS text
270 7820 aaronmk
    LANGUAGE plpgsql IMMUTABLE STRICT
271 6222 aaronmk
    AS $$
272
DECLARE
273 6271 aaronmk
    match text := map -> value;
274 6222 aaronmk
BEGIN
275 6271 aaronmk
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
276
        match := map -> '*'; -- use default entry
277
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
278
        END IF;
279
    END IF;
280
281
    -- Interpret result
282 6243 aaronmk
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
283
    ELSIF match = '*' THEN RETURN value;
284
    ELSE RETURN match;
285 6222 aaronmk
    END IF;
286
END;
287
$$;
288
289
290
--
291 8183 aaronmk
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
292 5408 aaronmk
--
293
294
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
295
    LANGUAGE sql IMMUTABLE
296
    AS $_$
297 7289 aaronmk
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
298 5408 aaronmk
$_$;
299
300
301
--
302 8183 aaronmk
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
303 2940 aaronmk
--
304
305 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
306 2940 aaronmk
    LANGUAGE sql IMMUTABLE
307
    AS $_$
308 8183 aaronmk
SELECT util.join_strs(value, '; ')
309 2940 aaronmk
FROM
310
(
311
    SELECT *
312
    FROM
313
    (
314
        SELECT
315
        DISTINCT ON (value)
316
        *
317
        FROM
318
        (VALUES
319 4012 aaronmk
              (1, $1)
320
            , (2, $2)
321
            , (3, $3)
322
            , (4, $4)
323
            , (5, $5)
324
            , (6, $6)
325
            , (7, $7)
326
            , (8, $8)
327
            , (9, $9)
328
            , (10, $10)
329 2940 aaronmk
        )
330
        AS v (sort_order, value)
331 4011 aaronmk
        WHERE value IS NOT NULL
332 2940 aaronmk
    )
333
    AS v
334
    ORDER BY sort_order
335
)
336
AS v
337
$_$;
338
339
340
--
341 8183 aaronmk
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
342 7140 aaronmk
--
343
344
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
345
    LANGUAGE sql IMMUTABLE
346
    AS $_$
347
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
348
$_$;
349
350
351
--
352 8183 aaronmk
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
353 6354 aaronmk
--
354
355
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
356
    LANGUAGE sql IMMUTABLE
357
    AS $_$
358 8183 aaronmk
SELECT util.join_strs(value, ' ')
359 6354 aaronmk
FROM
360
(
361
    SELECT *
362
    FROM
363
    (
364
        SELECT
365
        DISTINCT ON (value)
366
        *
367
        FROM
368
        (VALUES
369
              (1, $1)
370
            , (2, $2)
371
            , (3, $3)
372
            , (4, $4)
373
            , (5, $5)
374
            , (6, $6)
375
            , (7, $7)
376
            , (8, $8)
377
            , (9, $9)
378
            , (10, $10)
379
        )
380
        AS v (sort_order, value)
381
        WHERE value IS NOT NULL
382
    )
383
    AS v
384
    ORDER BY sort_order
385
)
386
AS v
387
$_$;
388
389
390
--
391 8183 aaronmk
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
392 5408 aaronmk
--
393
394
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
395
    LANGUAGE sql IMMUTABLE
396
    AS $_$
397 7289 aaronmk
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
398 5408 aaronmk
$_$;
399
400
401
--
402 8183 aaronmk
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
403 6316 aaronmk
--
404
405
CREATE FUNCTION _not(value boolean) RETURNS boolean
406
    LANGUAGE sql IMMUTABLE STRICT
407
    AS $_$
408
SELECT NOT $1
409
$_$;
410
411
412
--
413 8183 aaronmk
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
414 7104 aaronmk
--
415
416
CREATE FUNCTION _now() RETURNS timestamp with time zone
417
    LANGUAGE sql STABLE
418
    AS $$
419
SELECT now()
420
$$;
421
422
423
--
424 8183 aaronmk
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
425 2949 aaronmk
--
426
427 4475 aaronmk
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
428 2949 aaronmk
    LANGUAGE plpgsql IMMUTABLE
429
    AS $$
430
DECLARE
431 8183 aaronmk
    type util.datatype NOT NULL := type; -- add NOT NULL
432 2949 aaronmk
BEGIN
433 4475 aaronmk
    IF type = 'str' THEN RETURN nullif(value::text, "null");
434 2722 aaronmk
    -- Invalid value is ignored, but invalid null value generates error
435 2949 aaronmk
    ELSIF type = 'float' THEN
436 2722 aaronmk
        DECLARE
437
            -- Outside the try block so that invalid null value generates error
438 2949 aaronmk
            "null" double precision := "null"::double precision;
439 2722 aaronmk
        BEGIN
440 2949 aaronmk
            RETURN nullif(value::double precision, "null");
441 2722 aaronmk
        EXCEPTION
442 2949 aaronmk
            WHEN data_exception THEN RETURN value; -- ignore invalid value
443 2722 aaronmk
        END;
444 2610 aaronmk
    END IF;
445
END;
446
$$;
447
448
449
--
450 8183 aaronmk
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
451 4479 aaronmk
--
452
453
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
454
    LANGUAGE sql IMMUTABLE
455
    AS $_$
456 8183 aaronmk
SELECT util."_nullIf"($1, $2, $3::util.datatype)
457 4479 aaronmk
$_$;
458
459
460
--
461 8183 aaronmk
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
462 6355 aaronmk
--
463
464
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
465
    LANGUAGE sql IMMUTABLE
466
    AS $_$
467
SELECT bool_or(value)
468
FROM
469
(VALUES
470
      ($1)
471
    , ($2)
472
    , ($3)
473
    , ($4)
474
    , ($5)
475
)
476
AS v (value)
477
$_$;
478
479
480
--
481 8183 aaronmk
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
482 6437 aaronmk
--
483
484
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.';
485
486
487
--
488 8183 aaronmk
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
489 7706 aaronmk
--
490
491
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
492
    LANGUAGE sql IMMUTABLE
493
    AS $_$
494
SELECT $2 - $1
495
$_$;
496
497
498
--
499 8183 aaronmk
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
500 6793 aaronmk
--
501
502
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
503
    LANGUAGE sql IMMUTABLE STRICT
504
    AS $_$
505
SELECT regexp_split_to_table($1, $2)
506
$_$;
507
508
509
--
510 9959 aaronmk
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
511
--
512
513
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
514
    LANGUAGE sql IMMUTABLE
515
    AS $_$
516
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
517
$_$;
518
519
520
--
521
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
522
--
523
524
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
525
    LANGUAGE plpgsql IMMUTABLE
526
    AS $$
527
DECLARE
528
	value_cmp         state%TYPE = ARRAY[value];
529
	state             state%TYPE = COALESCE(state, value_cmp);
530
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
531
BEGIN
532
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
533
END;
534
$$;
535
536
537
--
538 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
539 8104 aaronmk
--
540
541
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
542
    LANGUAGE sql STABLE STRICT
543
    AS $_$
544
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
545
$_$;
546
547
548
--
549 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
550 8105 aaronmk
--
551
552
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
553
    LANGUAGE plpgsql STRICT
554
    AS $_$
555
BEGIN
556
    -- not yet clustered (ARRAY[] compares NULLs literally)
557 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
558 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
559
    END IF;
560
END;
561
$_$;
562
563
564
--
565 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
566 8105 aaronmk
--
567
568
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
569
570
571
--
572 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
573 8180 aaronmk
--
574
575
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
576
    LANGUAGE plpgsql STRICT
577
    AS $$
578
BEGIN
579 8183 aaronmk
    PERFORM util.col_type(col);
580 8180 aaronmk
    RETURN true;
581
EXCEPTION
582
    WHEN undefined_column THEN RETURN false;
583
END;
584
$$;
585
586
587
--
588 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
589 8084 aaronmk
--
590
591
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
592 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
593 8084 aaronmk
    AS $$
594
DECLARE
595 8183 aaronmk
    prefix text := util.name(type)||'.';
596 8084 aaronmk
BEGIN
597
    RETURN QUERY
598 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
599
        FROM util.col_names(type) f (name_);
600 8084 aaronmk
END;
601
$$;
602
603
604
--
605 8183 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
606 8082 aaronmk
--
607
608
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
609 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
610 8082 aaronmk
    AS $_$
611
BEGIN
612
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
613
END;
614
$_$;
615
616
617
--
618 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
619 8151 aaronmk
--
620
621
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
622
    LANGUAGE sql STABLE STRICT
623
    AS $_$
624
SELECT attname::text
625
FROM pg_attribute
626
WHERE attrelid = $1 AND attnum >= 1
627
ORDER BY attnum
628
$_$;
629
630
631
--
632 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
633 8106 aaronmk
--
634
635
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
636 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
637
    AS $$
638
DECLARE
639
    type regtype;
640
BEGIN
641
    SELECT atttypid FROM pg_attribute
642
    WHERE attrelid = col.table_ AND attname = col.name
643
    INTO STRICT type
644
    ;
645
    RETURN type;
646
EXCEPTION
647 8171 aaronmk
    WHEN no_data_found THEN
648 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
649
            concat('undefined column: ', col.name);
650 8169 aaronmk
END;
651
$$;
652 8106 aaronmk
653
654
--
655 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
656 8095 aaronmk
--
657
658
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
659
    LANGUAGE sql IMMUTABLE STRICT
660
    AS $_$
661
SELECT position($1 in $2) > 0 /*1-based offset*/
662
$_$;
663
664
665
--
666 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
667 8094 aaronmk
--
668
669
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
670
    LANGUAGE plpgsql STRICT
671
    AS $$
672
BEGIN
673
    EXECUTE sql;
674
EXCEPTION
675 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
676
    WHEN duplicate_column THEN NULL;
677 8094 aaronmk
END;
678
$$;
679
680
681
--
682 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
683 8094 aaronmk
--
684
685
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
686
687
688
--
689 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
690
--
691
692
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
693
    LANGUAGE sql STRICT
694
    AS $_$
695
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
696
$_$;
697
698
699
--
700
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
701
--
702
703
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
704
705
706
--
707 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
708 8086 aaronmk
--
709
710
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
711 8138 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
712 8086 aaronmk
    AS $_$
713 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
714 8086 aaronmk
$_$;
715
716
717
--
718 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
719
--
720
721
CREATE FUNCTION eval(sql text) RETURNS void
722
    LANGUAGE plpgsql STRICT
723
    AS $$
724
BEGIN
725
    RAISE NOTICE '%', sql;
726
    EXECUTE sql;
727
END;
728
$$;
729
730
731
--
732 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
733 8182 aaronmk
--
734
735
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
736
    LANGUAGE sql STABLE STRICT
737
    AS $_$
738
SELECT col_name
739
FROM unnest($2) s (col_name)
740 8183 aaronmk
WHERE util.col_exists(($1, col_name))
741 8182 aaronmk
$_$;
742
743
744
--
745 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
746
--
747
748
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
749
    LANGUAGE plpgsql STRICT
750
    AS $_$
751
DECLARE
752
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
753
$$||query;
754
BEGIN
755
	EXECUTE mk_view;
756
EXCEPTION
757
WHEN invalid_table_definition THEN
758 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
759
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
760
	THEN
761 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
762
		EXECUTE mk_view;
763
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
764
	END IF;
765
END;
766
$_$;
767
768
769
--
770
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
771
--
772
773
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
774
775
776
--
777 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
778 8085 aaronmk
--
779
780
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
781
    LANGUAGE sql IMMUTABLE STRICT
782
    AS $_$
783
SELECT substring($2 for length($1)) = $1
784
$_$;
785
786
787
--
788 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
789 4009 aaronmk
--
790
791 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
792 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
793 4009 aaronmk
    AS $_$
794 4054 aaronmk
SELECT $1 || $3 || $2
795 2595 aaronmk
$_$;
796
797
798
--
799 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
800
--
801
802
CREATE FUNCTION map_filter_insert() RETURNS trigger
803
    LANGUAGE plpgsql
804
    AS $$
805
BEGIN
806
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
807
	RETURN new;
808
END;
809
$$;
810
811
812
--
813 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
814 8146 aaronmk
--
815
816
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
817
    LANGUAGE plpgsql STABLE STRICT
818
    AS $_$
819
DECLARE
820
    value text;
821
BEGIN
822
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
823 8149 aaronmk
        INTO value USING key;
824 8146 aaronmk
    RETURN value;
825
END;
826
$_$;
827
828
829
--
830 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
831 8150 aaronmk
--
832
833
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
834
    LANGUAGE plpgsql STABLE STRICT
835
    AS $_$
836
BEGIN
837
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
838
END;
839
$_$;
840
841
842
--
843 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
844
--
845
846
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
847
    LANGUAGE sql STRICT
848
    AS $_$
849
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
850
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
851
||quote_literal($2))
852
$_$;
853
854
855
--
856
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
857
--
858
859
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
860
861
862
--
863 8187 aaronmk
-- Name: mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
864
--
865
866
CREATE FUNCTION mk_derived_col(col col_ref, expr text) RETURNS void
867
    LANGUAGE plpgsql STRICT
868
    AS $_$
869
DECLARE
870
    type regtype = util.typeof(expr, col.table_::text::regtype);
871
    col_name_sql text = quote_ident(col.name);
872
BEGIN
873
    PERFORM util.create_if_not_exists($$
874
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;
875
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
876
$$||expr||$$;
877
$$);
878
END;
879
$_$;
880
881
882
--
883 8188 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
884
--
885
886
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text) IS 'idempotent';
887
888
889
--
890 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
891 8139 aaronmk
--
892
893
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
894 8141 aaronmk
    LANGUAGE sql STRICT
895 8139 aaronmk
    AS $_$
896 8183 aaronmk
SELECT util.create_if_not_exists($$
897 8141 aaronmk
CREATE TABLE $$||$1||$$
898 8139 aaronmk
(
899 8183 aaronmk
    LIKE util.map INCLUDING ALL
900 10110 aaronmk
);
901
902
CREATE TRIGGER map_filter_insert
903
  BEFORE INSERT
904
  ON $$||$1||$$
905
  FOR EACH ROW
906
  EXECUTE PROCEDURE util.map_filter_insert();
907 8141 aaronmk
$$)
908 8139 aaronmk
$_$;
909
910
911
--
912 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
913
--
914
915
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
916
    LANGUAGE sql STRICT
917
    AS $_$
918
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
919
$_$;
920
921
922
--
923
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
924
--
925
926
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
927
928
929
--
930 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
931
--
932
933
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
934
    LANGUAGE plpgsql STRICT
935
    AS $_$
936
BEGIN
937
	EXECUTE $$
938
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
939
  RETURNS SETOF $$||view_||$$ AS
940
$BODY1$
941
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$
942 8331 aaronmk
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN COALESCE($2, 0)+1 AND COALESCE(COALESCE($2, 0)+1 + $1 - 1, 2147483647)
943 8325 aaronmk
$BODY1$
944
  LANGUAGE sql STABLE
945
  COST 100
946
  ROWS 1000
947
$$;
948 8326 aaronmk
-- Also create subset function which turns off enable_sort
949
	EXECUTE $$
950
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
951
  RETURNS SETOF $$||view_||$$
952
  SET enable_sort TO 'off'
953
  AS
954
$BODY1$
955 8328 aaronmk
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$($2, $3)
956 8326 aaronmk
$BODY1$
957
  LANGUAGE sql STABLE
958
  COST 100
959
  ROWS 1000
960
;
961
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
962
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
963
If you want to run EXPLAIN and get expanded output, use the regular subset
964
function instead. (When a config param is set on a function, EXPLAIN produces
965
just a function scan.)
966
';
967
$$;
968 8325 aaronmk
END;
969
$_$;
970
971
972
--
973 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
974 8083 aaronmk
--
975
976
CREATE FUNCTION name(type regtype) RETURNS text
977 8097 aaronmk
    LANGUAGE sql STABLE STRICT
978 8083 aaronmk
    AS $_$
979
SELECT typname::text FROM pg_type WHERE oid = $1
980
$_$;
981
982
983
--
984 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
985
--
986
987
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
988
    LANGUAGE sql IMMUTABLE
989
    AS $_$
990
SELECT $1 IS NOT NULL AND array_length($1, 1)/*ARRAY[]->NULL*/ IS NOT NULL
991
$_$;
992
993
994
--
995 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
996
--
997
998
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
999 9957 aaronmk
    LANGUAGE sql IMMUTABLE
1000 9956 aaronmk
    AS $_$
1001
SELECT $1 IS NOT NULL
1002
$_$;
1003
1004
1005
--
1006 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1007
--
1008
1009
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1010
    LANGUAGE plpgsql IMMUTABLE STRICT
1011
    AS $$
1012
BEGIN
1013
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1014
END;
1015
$$;
1016
1017
1018
--
1019 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1020 8137 aaronmk
--
1021
1022 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1023 8137 aaronmk
    LANGUAGE sql STRICT
1024
    AS $_$
1025 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1026 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1027 8183 aaronmk
FROM util.col_names($1::text::regtype) f (name)
1028 8137 aaronmk
$_$;
1029
1030
1031
--
1032 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1033 8137 aaronmk
--
1034
1035 8148 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1036 8137 aaronmk
1037
1038
--
1039 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1040 8143 aaronmk
--
1041
1042
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1043
    LANGUAGE sql STRICT
1044
    AS $_$
1045 8183 aaronmk
SELECT util.mk_map_table($1);
1046
SELECT util.truncate($1);
1047 8143 aaronmk
$_$;
1048
1049
1050
--
1051 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1052
--
1053
1054
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1055
    LANGUAGE sql STRICT
1056
    AS $_$
1057
SELECT util.eval(
1058
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1059
$_$;
1060
1061
1062
--
1063 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1064 8153 aaronmk
--
1065
1066
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1067
    LANGUAGE plpgsql STRICT
1068
    AS $_$
1069
DECLARE
1070 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
1071
    new text[] = ARRAY(SELECT util.map_values(names));
1072 8153 aaronmk
BEGIN
1073
    old = old[1:array_length(new, 1)]; -- truncate to same length
1074 8212 aaronmk
    PERFORM util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1075 8153 aaronmk
        ||quote_ident(key)||$$ TO $$||quote_ident(value))
1076
    FROM each(hstore(old, new));
1077
END;
1078
$_$;
1079
1080
1081
--
1082 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1083 8153 aaronmk
--
1084
1085
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1086
1087
1088
--
1089 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1090 8107 aaronmk
--
1091
1092
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1093
    LANGUAGE plpgsql STRICT
1094
    AS $_$
1095
DECLARE
1096
    sql text = $$ALTER TABLE $$||table_||$$
1097
$$||NULLIF(array_to_string(ARRAY(
1098
    SELECT
1099
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1100
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1101
    FROM
1102
    (
1103
        SELECT
1104
          quote_ident(col_name) AS col_name_sql
1105 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
1106 8107 aaronmk
        , type AS target_type
1107
        FROM unnest(col_casts)
1108
    ) s
1109
    WHERE curr_type != target_type
1110
), '
1111
, '), '');
1112
BEGIN
1113
    RAISE NOTICE '%', sql;
1114
    EXECUTE COALESCE(sql, '');
1115
END;
1116
$_$;
1117
1118
1119
--
1120 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1121 8107 aaronmk
--
1122
1123
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS 'idempotent';
1124
1125
1126
--
1127 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1128 8144 aaronmk
--
1129
1130
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1131 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
1132 8144 aaronmk
    AS $_$
1133
DECLARE
1134
    hstore hstore;
1135
BEGIN
1136
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1137
        table_||$$))$$ INTO STRICT hstore;
1138
    RETURN hstore;
1139
END;
1140
$_$;
1141
1142
1143
--
1144 10112 aaronmk
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1145
--
1146
1147
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1148
    LANGUAGE sql STABLE STRICT
1149
    AS $_$
1150
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1151
$_$;
1152
1153
1154
--
1155 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1156 8088 aaronmk
--
1157
1158
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1159
    LANGUAGE plpgsql STRICT
1160
    AS $_$
1161
DECLARE
1162
    row record;
1163
BEGIN
1164 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1165 8088 aaronmk
    LOOP
1166
        IF row.global_name != row.name THEN
1167
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1168
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1169
        END IF;
1170
    END LOOP;
1171
END;
1172
$_$;
1173
1174
1175
--
1176 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1177 8088 aaronmk
--
1178
1179
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1180
1181
1182
--
1183 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1184 8142 aaronmk
--
1185
1186
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1187
    LANGUAGE plpgsql STRICT
1188
    AS $_$
1189
BEGIN
1190
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1191
END;
1192
$_$;
1193
1194
1195
--
1196 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1197 8142 aaronmk
--
1198
1199
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1200
1201
1202
--
1203 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1204
--
1205
1206
CREATE FUNCTION try_create(sql text) RETURNS void
1207
    LANGUAGE plpgsql STRICT
1208
    AS $$
1209
BEGIN
1210
    EXECUTE sql;
1211
EXCEPTION
1212 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1213 8199 aaronmk
    WHEN undefined_column THEN NULL;
1214
    WHEN duplicate_column THEN NULL;
1215
END;
1216
$$;
1217
1218
1219
--
1220
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1221
--
1222
1223
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1224
1225
1226
--
1227 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1228
--
1229
1230
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1231
    LANGUAGE sql STRICT
1232
    AS $_$
1233
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1234
$_$;
1235
1236
1237
--
1238
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1239
--
1240
1241
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1242
1243
1244
--
1245 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1246
--
1247
1248
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1249
    LANGUAGE sql IMMUTABLE
1250
    AS $_$
1251
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1252
$_$;
1253
1254
1255
--
1256 8324 aaronmk
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
1257
--
1258
1259
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1260
    LANGUAGE sql STABLE STRICT
1261
    SET search_path TO pg_temp
1262
    AS $_$
1263
SELECT $1::text
1264
$_$;
1265
1266
1267
--
1268 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
1269
--
1270
1271
CREATE FUNCTION typeof(expr text, table_ regtype) RETURNS regtype
1272
    LANGUAGE plpgsql STABLE STRICT
1273
    AS $_$
1274
DECLARE
1275
    type regtype;
1276
BEGIN
1277
    EXECUTE $$SELECT pg_typeof($$||expr||$$) FROM (SELECT (NULL::$$||table_||
1278
    $$).*) _s$$ INTO STRICT type;
1279
    RETURN type;
1280
END;
1281
$_$;
1282
1283
1284
--
1285 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
1286
--
1287
1288
CREATE AGGREGATE all_same(anyelement) (
1289
    SFUNC = all_same_transform,
1290
    STYPE = anyarray,
1291
    FINALFUNC = all_same_final
1292
);
1293
1294
1295
--
1296
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
1297
--
1298
1299
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
1300
1301
1302
--
1303 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1304 2595 aaronmk
--
1305
1306
CREATE AGGREGATE join_strs(text, text) (
1307 4052 aaronmk
    SFUNC = join_strs_transform,
1308 4010 aaronmk
    STYPE = text
1309 2595 aaronmk
);
1310
1311
1312 8147 aaronmk
--
1313 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1314 8147 aaronmk
--
1315
1316
CREATE OPERATOR -> (
1317
    PROCEDURE = map_get,
1318
    LEFTARG = regclass,
1319
    RIGHTARG = text
1320
);
1321
1322
1323 8140 aaronmk
SET default_tablespace = '';
1324
1325
SET default_with_oids = false;
1326
1327 2107 aaronmk
--
1328 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
1329 8140 aaronmk
--
1330
1331
CREATE TABLE map (
1332
    "from" text NOT NULL,
1333 8158 aaronmk
    "to" text,
1334
    filter text,
1335
    notes text
1336 8140 aaronmk
);
1337
1338
1339
--
1340 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
1341 8140 aaronmk
--
1342
1343
1344
1345
--
1346 8183 aaronmk
-- Name: map_pkey; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
1347 8140 aaronmk
--
1348
1349
ALTER TABLE ONLY map
1350
    ADD CONSTRAINT map_pkey PRIMARY KEY ("from");
1351
1352
1353
--
1354 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
1355
--
1356
1357
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
1358
1359
1360
--
1361 2136 aaronmk
-- PostgreSQL database dump complete
1362
--