Project

General

Profile

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