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