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