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 12320 aaronmk
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
590
--
591
592
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
593
    LANGUAGE sql
594
    AS $_$
595
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
596
$_$;
597
598
599
--
600 10305 aaronmk
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
601
--
602
603
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
604
    LANGUAGE sql IMMUTABLE
605
    AS $_$
606
SELECT pg_catalog.array_fill($1, ARRAY[$2])
607
$_$;
608
609
610
--
611 10303 aaronmk
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
612
--
613
614
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
615 10354 aaronmk
    LANGUAGE sql IMMUTABLE
616 10303 aaronmk
    AS $_$
617 10321 aaronmk
SELECT util.array_length($1, 1)
618 10303 aaronmk
$_$;
619
620
621
--
622 10304 aaronmk
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
623
--
624
625
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
626 10354 aaronmk
    LANGUAGE sql IMMUTABLE
627 10304 aaronmk
    AS $_$
628 10354 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
629 10304 aaronmk
$_$;
630
631
632
--
633
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
634
--
635
636 12235 aaronmk
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
637
returns 0 instead of NULL for empty arrays
638
';
639 10304 aaronmk
640
641
--
642 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
643 8104 aaronmk
--
644
645
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
646
    LANGUAGE sql STABLE STRICT
647
    AS $_$
648
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
649
$_$;
650
651
652
--
653 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
654 8105 aaronmk
--
655
656
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
657
    LANGUAGE plpgsql STRICT
658
    AS $_$
659
BEGIN
660
    -- not yet clustered (ARRAY[] compares NULLs literally)
661 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
662 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
663
    END IF;
664
END;
665
$_$;
666
667
668
--
669 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
670 8105 aaronmk
--
671
672 12235 aaronmk
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
673
idempotent
674
';
675 8105 aaronmk
676
677
--
678 10986 aaronmk
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
679
--
680
681
CREATE FUNCTION col__min(col col_ref) RETURNS integer
682
    LANGUAGE sql STABLE
683
    AS $_$
684
SELECT util.eval2val($$
685
SELECT $$||quote_ident($1.name)||$$
686
FROM $$||$1.table_||$$
687
ORDER BY $$||quote_ident($1.name)||$$ ASC
688
LIMIT 1
689
$$, NULL::integer)
690
$_$;
691
692
693
--
694 10136 aaronmk
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
695
--
696
697
CREATE FUNCTION col_comment(col col_ref) RETURNS text
698
    LANGUAGE plpgsql STABLE STRICT
699
    AS $$
700
DECLARE
701
	comment text;
702
BEGIN
703
	SELECT description
704
	FROM pg_attribute
705
	LEFT JOIN pg_description ON objoid = attrelid
706
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
707
	WHERE attrelid = col.table_ AND attname = col.name
708
	INTO STRICT comment
709
	;
710
	RETURN comment;
711
EXCEPTION
712
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
713
END;
714
$$;
715
716
717
--
718 10130 aaronmk
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
719
--
720
721
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
722
    LANGUAGE plpgsql STABLE STRICT
723
    AS $$
724
DECLARE
725
	default_sql text;
726
BEGIN
727
	SELECT adsrc
728
	FROM pg_attribute
729
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
730
	WHERE attrelid = col.table_ AND attname = col.name
731
	INTO STRICT default_sql
732
	;
733
	RETURN default_sql;
734
EXCEPTION
735
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
736
END;
737
$$;
738
739
740
--
741 10134 aaronmk
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
742
--
743
744
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
745
    LANGUAGE sql STABLE
746
    AS $_$
747
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
748
$_$;
749
750
751
--
752
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
753
--
754
755 12235 aaronmk
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
756
ret_type_null: NULL::ret_type
757
';
758 10134 aaronmk
759
760
--
761 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
762 8180 aaronmk
--
763
764
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
765
    LANGUAGE plpgsql STRICT
766
    AS $$
767
BEGIN
768 8183 aaronmk
    PERFORM util.col_type(col);
769 8180 aaronmk
    RETURN true;
770
EXCEPTION
771
    WHEN undefined_column THEN RETURN false;
772
END;
773
$$;
774
775
776
--
777 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
778 8084 aaronmk
--
779
780
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
781 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
782 8084 aaronmk
    AS $$
783
DECLARE
784 8183 aaronmk
    prefix text := util.name(type)||'.';
785 8084 aaronmk
BEGIN
786
    RETURN QUERY
787 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
788
        FROM util.col_names(type) f (name_);
789 8084 aaronmk
END;
790
$$;
791
792
793
--
794 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
795 8151 aaronmk
--
796
797
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
798
    LANGUAGE sql STABLE STRICT
799
    AS $_$
800
SELECT attname::text
801
FROM pg_attribute
802 10158 aaronmk
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
803 8151 aaronmk
ORDER BY attnum
804
$_$;
805
806
807
--
808 11667 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
809
--
810
811
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
812
    LANGUAGE plpgsql STABLE STRICT
813
    AS $_$
814
BEGIN
815
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
816
END;
817
$_$;
818
819
820
--
821 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
822 8106 aaronmk
--
823
824
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
825 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
826
    AS $$
827
DECLARE
828
    type regtype;
829
BEGIN
830
    SELECT atttypid FROM pg_attribute
831
    WHERE attrelid = col.table_ AND attname = col.name
832
    INTO STRICT type
833
    ;
834
    RETURN type;
835
EXCEPTION
836 8171 aaronmk
    WHEN no_data_found THEN
837 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
838
            concat('undefined column: ', col.name);
839 8169 aaronmk
END;
840
$$;
841 8106 aaronmk
842
843
--
844 11005 aaronmk
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
845
--
846
847
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
848
    LANGUAGE sql IMMUTABLE
849
    AS $_$
850
SELECT util.esc_name__append($2, $1)
851
$_$;
852
853
854
--
855 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
856 8095 aaronmk
--
857
858
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
859 10388 aaronmk
    LANGUAGE sql IMMUTABLE
860 8095 aaronmk
    AS $_$
861
SELECT position($1 in $2) > 0 /*1-based offset*/
862
$_$;
863
864
865
--
866 12288 aaronmk
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
867
--
868
869
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
870
    LANGUAGE sql
871
    AS $_$
872
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
873
$_$;
874
875
876
--
877 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
878 8094 aaronmk
--
879
880
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
881
    LANGUAGE plpgsql STRICT
882
    AS $$
883
BEGIN
884 10146 aaronmk
    PERFORM util.eval(sql);
885 8094 aaronmk
EXCEPTION
886 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
887 10181 aaronmk
    WHEN duplicate_object THEN NULL; -- e.g. constraint
888 8103 aaronmk
    WHEN duplicate_column THEN NULL;
889 10244 aaronmk
    WHEN invalid_table_definition THEN
890
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
891
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
892
        END IF;
893 8094 aaronmk
END;
894
$$;
895
896
897
--
898 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
899 8094 aaronmk
--
900
901 12235 aaronmk
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
902
idempotent
903
';
904 8094 aaronmk
905
906
--
907 12250 aaronmk
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
908
--
909
910
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
911
    LANGUAGE sql IMMUTABLE
912
    AS $_$
913
/* newline before so the query starts at the beginning of the line.
914
newline after to visually separate queries from one another. */
915
SELECT util.raise_notice($$
916
$$||$1||$$
917
$$)
918
$_$;
919
920
921
--
922 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
923
--
924
925
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
926
    LANGUAGE sql STABLE STRICT
927
    AS $_$
928
SELECT util.eval2set($$
929
SELECT col
930
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
931
LEFT JOIN $$||$2||$$ ON "to" = col
932
WHERE "from" IS NULL
933
$$, NULL::text)
934
$_$;
935
936
937
--
938
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
939
--
940
941 12235 aaronmk
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
942
gets table_''s derived columns (all the columns not in the names table)
943
';
944 10364 aaronmk
945
946
--
947 12298 aaronmk
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
948 12044 aaronmk
--
949
950 12298 aaronmk
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
951 12044 aaronmk
    LANGUAGE sql STABLE
952
    AS $_$
953 12300 aaronmk
SELECT * FROM util.diff($1::text, $2::text, $3,
954
	util.has_single_row($1) AND util.has_single_row($2))
955 12298 aaronmk
$_$;
956
957
958
--
959
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
960
--
961
962
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
963
col_type_null (*required*): NULL::shared_base_type
964
usage:
965
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
966
';
967
968
969
--
970
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
971
--
972
973
CREATE FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
974
    LANGUAGE sql STABLE
975
    AS $_$
976 12044 aaronmk
SELECT * FROM
977 12184 aaronmk
util.eval2col_pair($$
978 12284 aaronmk
/* need to explicitly cast each side to the return type because this does not
979
happen automatically even when an implicit cast is available */
980
SELECT left_::$$||pg_typeof($3)||$$, right_::$$||pg_typeof($3)||$$
981 12299 aaronmk
FROM $$||$1||$$ left_
982
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
983 12308 aaronmk
$$||util._if($4, ''::text, $$ON left_ = right_
984
$$)||
985
$$WHERE left_ IS DISTINCT FROM right_
986 12044 aaronmk
ORDER BY left_, right_
987 12308 aaronmk
$$, $3)
988 12044 aaronmk
$_$;
989
990
991
--
992 12298 aaronmk
-- Name: FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
993 12280 aaronmk
--
994
995 12298 aaronmk
COMMENT ON FUNCTION diff(left_ text, right_ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
996 12280 aaronmk
col_type_null (*required*): NULL::col_type
997 12299 aaronmk
single_row: whether the tables consist of a single row, which should be
998
	displayed side-by-side
999 12282 aaronmk
1000
to run EXPLAIN on the FULL JOIN query:
1001
# run this function
1002
# look for a NOTICE containing the expanded query that it ran
1003
# run EXPLAIN on this expanded query
1004 12280 aaronmk
';
1005
1006
1007
--
1008 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1009
--
1010
1011
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1012
    LANGUAGE sql STRICT
1013
    AS $_$
1014
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1015
$_$;
1016
1017
1018
--
1019
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1020
--
1021
1022 12235 aaronmk
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1023
idempotent
1024
';
1025 8200 aaronmk
1026
1027
--
1028 12292 aaronmk
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1029 10362 aaronmk
--
1030
1031 12292 aaronmk
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1032 10362 aaronmk
    LANGUAGE sql STRICT
1033
    AS $_$
1034
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1035 12292 aaronmk
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1036 10362 aaronmk
$_$;
1037
1038
1039
--
1040 12292 aaronmk
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1041 10362 aaronmk
--
1042
1043 12292 aaronmk
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1044 12235 aaronmk
idempotent
1045
';
1046 10362 aaronmk
1047
1048
--
1049 12331 aaronmk
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1050
--
1051
1052
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1053
    LANGUAGE sql
1054
    AS $_$
1055
SELECT (CASE
1056
WHEN util.is_table($1) THEN util.drop_table($1::text)
1057
WHEN util.is_view($1)  THEN util.drop_view($1::text)
1058
-- otherwise, throw case_not_found error
1059
END)
1060
$_$;
1061
1062
1063
--
1064
-- Name: FUNCTION drop_relation(relation regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
1065
--
1066
1067
COMMENT ON FUNCTION drop_relation(relation regclass, force boolean) IS '
1068
idempotent
1069
';
1070
1071
1072
--
1073 12292 aaronmk
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1074 10150 aaronmk
--
1075
1076 12292 aaronmk
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1077 10150 aaronmk
    LANGUAGE sql STRICT
1078
    AS $_$
1079 12292 aaronmk
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1
1080
||util._if($2, $$ CASCADE$$, ''::text))
1081 10150 aaronmk
$_$;
1082
1083
1084
--
1085 12292 aaronmk
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1086 10150 aaronmk
--
1087
1088 12292 aaronmk
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1089 12235 aaronmk
idempotent
1090
';
1091 10150 aaronmk
1092
1093
--
1094 12292 aaronmk
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1095 12229 aaronmk
--
1096
1097 12292 aaronmk
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1098 12229 aaronmk
    LANGUAGE sql STRICT
1099
    AS $_$
1100 12292 aaronmk
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1
1101
||util._if($2, $$ CASCADE$$, ''::text))
1102 12229 aaronmk
$_$;
1103
1104
1105
--
1106 12292 aaronmk
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1107 12229 aaronmk
--
1108
1109 12292 aaronmk
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1110 12235 aaronmk
idempotent
1111
';
1112 12229 aaronmk
1113
1114
--
1115 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1116
--
1117
1118
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1119
    LANGUAGE sql IMMUTABLE
1120
    AS $_$
1121
SELECT util.array_fill($1, 0)
1122
$_$;
1123
1124
1125
--
1126
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1127
--
1128
1129 12235 aaronmk
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1130
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1131
';
1132 10322 aaronmk
1133
1134
--
1135 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1136 8086 aaronmk
--
1137
1138
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1139 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1140 8086 aaronmk
    AS $_$
1141 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1142 8086 aaronmk
$_$;
1143
1144
1145
--
1146 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1147
--
1148
1149
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1150
    LANGUAGE sql IMMUTABLE
1151
    AS $_$
1152
SELECT regexp_replace($2, '("?)$', $1||'\1')
1153
$_$;
1154
1155
1156
--
1157 9824 aaronmk
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1158
--
1159
1160
CREATE FUNCTION eval(sql text) RETURNS void
1161
    LANGUAGE plpgsql STRICT
1162
    AS $$
1163
BEGIN
1164 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1165
	EXECUTE sql;
1166 9824 aaronmk
END;
1167
$$;
1168
1169
1170
--
1171 12181 aaronmk
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1172
--
1173
1174
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1175
    LANGUAGE plpgsql
1176
    AS $$
1177
BEGIN
1178 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1179 12181 aaronmk
	RETURN QUERY EXECUTE sql;
1180
END;
1181
$$;
1182
1183
1184
--
1185
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1186
--
1187
1188 12235 aaronmk
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1189
col_type_null (*required*): NULL::col_type
1190
';
1191 12181 aaronmk
1192
1193
--
1194 12301 aaronmk
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1195
--
1196
1197
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1198
    LANGUAGE plpgsql
1199
    AS $$
1200
BEGIN
1201
	PERFORM util.debug_print_sql(sql);
1202
	RETURN QUERY EXECUTE sql;
1203
END;
1204
$$;
1205
1206
1207
--
1208 10363 aaronmk
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1209
--
1210
1211
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1212
    LANGUAGE plpgsql
1213
    AS $$
1214
BEGIN
1215 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1216 10363 aaronmk
	RETURN QUERY EXECUTE sql;
1217
END;
1218
$$;
1219
1220
1221
--
1222
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1223
--
1224
1225 12235 aaronmk
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1226
ret_type_null: NULL::ret_type
1227
';
1228 10363 aaronmk
1229
1230
--
1231 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1232 10128 aaronmk
--
1233
1234 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1235 10128 aaronmk
    LANGUAGE plpgsql
1236
    AS $$
1237
DECLARE
1238
	ret_val ret_type_null%TYPE;
1239
BEGIN
1240 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1241 10128 aaronmk
	EXECUTE sql INTO STRICT ret_val;
1242
	RETURN ret_val;
1243
END;
1244
$$;
1245
1246
1247
--
1248 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1249 10128 aaronmk
--
1250
1251 12235 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1252
ret_type_null: NULL::ret_type
1253
';
1254 10128 aaronmk
1255
1256
--
1257 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1258
--
1259
1260
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1261
    LANGUAGE sql
1262
    AS $_$
1263 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1264 10131 aaronmk
$_$;
1265
1266
1267
--
1268
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1269
--
1270
1271 12235 aaronmk
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1272
ret_type_null: NULL::ret_type
1273
';
1274 10131 aaronmk
1275
1276
--
1277 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1278
--
1279
1280
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1281
    LANGUAGE sql
1282
    AS $_$
1283
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1284
$_$;
1285
1286
1287
--
1288
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1289
--
1290
1291 12235 aaronmk
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1292
sql: can be NULL, which will be passed through
1293
ret_type_null: NULL::ret_type
1294
';
1295 10133 aaronmk
1296
1297
--
1298 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1299 8182 aaronmk
--
1300
1301
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1302
    LANGUAGE sql STABLE STRICT
1303
    AS $_$
1304
SELECT col_name
1305
FROM unnest($2) s (col_name)
1306 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1307 8182 aaronmk
$_$;
1308
1309
1310
--
1311 11830 aaronmk
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1312
--
1313
1314
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1315
    LANGUAGE sql
1316
    AS $_$
1317
SELECT util.eval2set($$EXPLAIN $$||$1)
1318
$_$;
1319
1320
1321
--
1322 11833 aaronmk
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1323
--
1324
1325
CREATE FUNCTION explain2notice(sql text) RETURNS void
1326
    LANGUAGE plpgsql
1327
    AS $_$
1328
BEGIN
1329
	RAISE NOTICE '%', $$EXPLAIN:
1330
$$||util.explain2str(sql);
1331
END;
1332
$_$;
1333
1334
1335
--
1336 11832 aaronmk
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1337
--
1338
1339
CREATE FUNCTION explain2str(sql text) RETURNS text
1340
    LANGUAGE sql
1341
    AS $_$
1342
SELECT util.join_strs(explain, $$
1343
$$) FROM util.explain($1)
1344
$_$;
1345
1346
1347 11835 aaronmk
SET default_tablespace = '';
1348
1349
SET default_with_oids = false;
1350
1351 11832 aaronmk
--
1352 11835 aaronmk
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace:
1353 11831 aaronmk
--
1354
1355 11835 aaronmk
CREATE TABLE explain (
1356
    line text NOT NULL
1357
);
1358
1359
1360
--
1361
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1362
--
1363
1364
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1365 11831 aaronmk
    LANGUAGE sql
1366
    AS $_$
1367 11835 aaronmk
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1368
$$||quote_nullable($1)||$$
1369 11831 aaronmk
)$$)
1370
$_$;
1371
1372
1373
--
1374 11836 aaronmk
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1375
--
1376
1377 12235 aaronmk
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1378
usage:
1379 11836 aaronmk
PERFORM util.explain2table($$
1380
query
1381 12235 aaronmk
$$);
1382
';
1383 11836 aaronmk
1384
1385
--
1386 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1387
--
1388
1389
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1390 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1391 10323 aaronmk
    AS $_$
1392 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1393
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1394
) END
1395 10323 aaronmk
$_$;
1396
1397
1398
--
1399
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1400
--
1401
1402 12235 aaronmk
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1403
ensures that an array will always have proper non-NULL dimensions
1404
';
1405 10323 aaronmk
1406
1407
--
1408 11695 aaronmk
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1409
--
1410
1411
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1412
    LANGUAGE plpgsql
1413
    AS $_$
1414
DECLARE
1415
	PG_EXCEPTION_DETAIL text;
1416
	recreate_users_cmd text = util.save_drop_views(users);
1417
BEGIN
1418
	PERFORM util.eval(cmd);
1419
	PERFORM util.eval(recreate_users_cmd);
1420
EXCEPTION
1421
WHEN dependent_objects_still_exist THEN
1422
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1423
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1424
	users = array(SELECT * FROM util.regexp_matches_group(
1425
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1426
	IF util.is_empty(users) THEN RAISE; END IF;
1427
	PERFORM util.force_recreate(cmd, users);
1428
END;
1429
$_$;
1430
1431
1432
--
1433
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1434
--
1435
1436 12235 aaronmk
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1437
idempotent
1438 11695 aaronmk
1439 12235 aaronmk
users: not necessary to provide this because it will be autopopulated
1440
';
1441 11695 aaronmk
1442
1443
--
1444 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1445
--
1446
1447
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1448
    LANGUAGE plpgsql STRICT
1449
    AS $_$
1450
DECLARE
1451
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1452
$$||query;
1453
BEGIN
1454
	EXECUTE mk_view;
1455
EXCEPTION
1456
WHEN invalid_table_definition THEN
1457 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1458
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1459
	THEN
1460 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1461
		EXECUTE mk_view;
1462
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1463
	END IF;
1464
END;
1465
$_$;
1466
1467
1468
--
1469
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1470
--
1471
1472 12235 aaronmk
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1473
idempotent
1474
';
1475 8321 aaronmk
1476
1477
--
1478 11655 aaronmk
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1479
--
1480
1481
CREATE FUNCTION grants_users() RETURNS SETOF text
1482
    LANGUAGE sql IMMUTABLE
1483
    AS $$
1484
VALUES ('bien_read'), ('public_')
1485
$$;
1486
1487
1488
--
1489 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1490 8085 aaronmk
--
1491
1492
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1493 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1494 8085 aaronmk
    AS $_$
1495
SELECT substring($2 for length($1)) = $1
1496
$_$;
1497
1498
1499
--
1500 12296 aaronmk
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1501
--
1502
1503
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1504
    LANGUAGE sql STABLE
1505
    AS $_$
1506
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1507
$_$;
1508
1509
1510
--
1511 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1512
--
1513
1514
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1515
    LANGUAGE sql IMMUTABLE
1516
    AS $_$
1517 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1518 10307 aaronmk
$_$;
1519
1520
1521
--
1522
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1523
--
1524
1525 12235 aaronmk
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1526
avoids repeating the same value for each key
1527
';
1528 10307 aaronmk
1529
1530
--
1531 12218 aaronmk
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1532
--
1533
1534
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1535
    LANGUAGE sql IMMUTABLE
1536
    AS $_$
1537 12222 aaronmk
SELECT COALESCE($1, $2)
1538 12218 aaronmk
$_$;
1539
1540
1541
--
1542
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1543
--
1544
1545 12235 aaronmk
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1546
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1547
';
1548 12218 aaronmk
1549
1550
--
1551 12285 aaronmk
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1552
--
1553
1554
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1555
    LANGUAGE sql
1556
    AS $_$
1557
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1558
$_$;
1559
1560
1561
--
1562 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1563
--
1564
1565
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1566
    LANGUAGE sql STABLE STRICT
1567
    AS $_$
1568
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1569
$_$;
1570
1571
1572
--
1573 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1574
--
1575
1576
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1577
    LANGUAGE sql IMMUTABLE
1578
    AS $_$
1579
SELECT util.array_length($1) = 0
1580
$_$;
1581
1582
1583
--
1584 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1585
--
1586
1587
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1588
    LANGUAGE sql IMMUTABLE
1589
    AS $_$
1590
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1591
$_$;
1592
1593
1594
--
1595 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1596
--
1597
1598
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1599
    LANGUAGE sql IMMUTABLE
1600
    AS $_$
1601
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1602
$_$;
1603
1604
1605
--
1606 12330 aaronmk
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1607
--
1608
1609
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1610 12332 aaronmk
    LANGUAGE sql STABLE
1611 12330 aaronmk
    AS $_$
1612
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1613
$_$;
1614
1615
1616
--
1617 12329 aaronmk
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1618
--
1619
1620
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1621 12332 aaronmk
    LANGUAGE sql STABLE
1622 12329 aaronmk
    AS $_$
1623
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1624
$_$;
1625
1626
1627
--
1628 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1629 4009 aaronmk
--
1630
1631 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1632 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
1633 4009 aaronmk
    AS $_$
1634 4054 aaronmk
SELECT $1 || $3 || $2
1635 2595 aaronmk
$_$;
1636
1637
1638
--
1639 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1640 10985 aaronmk
--
1641
1642 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1643 10985 aaronmk
    LANGUAGE sql IMMUTABLE
1644
    AS $_$
1645 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1646 10985 aaronmk
$_$;
1647
1648
1649
--
1650 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1651
--
1652
1653
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1654
    LANGUAGE sql IMMUTABLE
1655
    AS $_$
1656
SELECT ltrim($1, $$
1657
$$)
1658
$_$;
1659
1660
1661
--
1662 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1663
--
1664
1665
CREATE FUNCTION map_filter_insert() RETURNS trigger
1666
    LANGUAGE plpgsql
1667
    AS $$
1668
BEGIN
1669
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1670
	RETURN new;
1671
END;
1672
$$;
1673
1674
1675
--
1676 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1677 8146 aaronmk
--
1678
1679
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1680
    LANGUAGE plpgsql STABLE STRICT
1681
    AS $_$
1682
DECLARE
1683
    value text;
1684
BEGIN
1685
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1686 8149 aaronmk
        INTO value USING key;
1687 8146 aaronmk
    RETURN value;
1688
END;
1689
$_$;
1690
1691
1692
--
1693 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1694 10325 aaronmk
--
1695
1696 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1697 10353 aaronmk
    LANGUAGE sql IMMUTABLE
1698 10325 aaronmk
    AS $_$
1699 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
1700 10325 aaronmk
$_$;
1701
1702
1703
--
1704 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1705
--
1706
1707 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
1708
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
1709 10359 aaronmk
1710
[1] inlining of function calls, which is different from constant folding
1711
[2] _map()''s profiling query
1712
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1713
and map_nulls()''s profiling query
1714
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1715 10375 aaronmk
both take ~920 ms.
1716 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.
1717
';
1718 10359 aaronmk
1719
1720
--
1721 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1722 8150 aaronmk
--
1723
1724
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1725
    LANGUAGE plpgsql STABLE STRICT
1726
    AS $_$
1727
BEGIN
1728
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1729
END;
1730
$_$;
1731
1732
1733
--
1734 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1735
--
1736
1737 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1738 12228 aaronmk
    LANGUAGE sql
1739
    AS $_$
1740 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1741 12321 aaronmk
$$||util.ltrim_nl($2));
1742
-- make sure the created table has the correct estimated row count
1743
SELECT util.analyze_($1);
1744 12228 aaronmk
$_$;
1745
1746
1747
--
1748 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1749 12228 aaronmk
--
1750
1751 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1752 12235 aaronmk
idempotent
1753
';
1754 12228 aaronmk
1755
1756
--
1757 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1758
--
1759
1760 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1761 12234 aaronmk
    LANGUAGE sql
1762
    AS $_$
1763
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1764
$_$;
1765
1766
1767
--
1768 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1769 12234 aaronmk
--
1770
1771 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1772 12235 aaronmk
idempotent
1773
';
1774 12234 aaronmk
1775
1776
--
1777 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1778
--
1779
1780
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1781
    LANGUAGE sql STRICT
1782
    AS $_$
1783 10135 aaronmk
SELECT util.create_if_not_exists($$
1784
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1785 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1786 10135 aaronmk
||quote_literal($2)||$$;
1787 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1788
constant
1789
';
1790 10135 aaronmk
$$)
1791 8190 aaronmk
$_$;
1792
1793
1794
--
1795
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1796
--
1797
1798 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1799
idempotent
1800
';
1801 8190 aaronmk
1802
1803
--
1804 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1805 8187 aaronmk
--
1806
1807 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1808 8187 aaronmk
    LANGUAGE plpgsql STRICT
1809
    AS $_$
1810
DECLARE
1811
    type regtype = util.typeof(expr, col.table_::text::regtype);
1812
    col_name_sql text = quote_ident(col.name);
1813
BEGIN
1814 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1815
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1816 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1817
$$||expr||$$;
1818
$$);
1819
END;
1820
$_$;
1821
1822
1823
--
1824 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1825 8188 aaronmk
--
1826
1827 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1828
idempotent
1829
';
1830 8188 aaronmk
1831
1832
--
1833 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1834 8139 aaronmk
--
1835
1836
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1837 8141 aaronmk
    LANGUAGE sql STRICT
1838 8139 aaronmk
    AS $_$
1839 8183 aaronmk
SELECT util.create_if_not_exists($$
1840 8141 aaronmk
CREATE TABLE $$||$1||$$
1841 8139 aaronmk
(
1842 8183 aaronmk
    LIKE util.map INCLUDING ALL
1843 10110 aaronmk
);
1844
1845
CREATE TRIGGER map_filter_insert
1846
  BEFORE INSERT
1847
  ON $$||$1||$$
1848
  FOR EACH ROW
1849
  EXECUTE PROCEDURE util.map_filter_insert();
1850 8141 aaronmk
$$)
1851 8139 aaronmk
$_$;
1852
1853
1854
--
1855 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1856
--
1857
1858
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1859
    LANGUAGE sql IMMUTABLE
1860
    AS $_$
1861
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1862
$_$;
1863
1864
1865
--
1866 12272 aaronmk
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1867
--
1868
1869
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
1870
    LANGUAGE sql IMMUTABLE
1871
    AS $_$
1872
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
1873
$_$;
1874
1875
1876
--
1877
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
1878
--
1879
1880
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
1881
usage:
1882
for *1* schema arg:
1883
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
1884
	-- 2 params are needed to use the correct variant of mk_set_search_path()
1885
';
1886
1887
1888
--
1889 12270 aaronmk
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
1890
--
1891
1892
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
1893
    LANGUAGE sql IMMUTABLE
1894
    AS $_$
1895
SELECT $$SET LOCAL search_path TO $$||$1
1896
$_$;
1897
1898
1899
--
1900 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1901
--
1902
1903
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1904
    LANGUAGE sql STRICT
1905
    AS $_$
1906 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1907 10113 aaronmk
$_$;
1908
1909
1910
--
1911
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1912
--
1913
1914 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1915
idempotent
1916
';
1917 10113 aaronmk
1918
1919
--
1920 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1921
--
1922
1923
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1924
    LANGUAGE plpgsql STRICT
1925
    AS $_$
1926
DECLARE
1927
	view_qual_name text = util.qual_name(view_);
1928
BEGIN
1929
	EXECUTE $$
1930
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1931
  RETURNS SETOF $$||view_||$$ AS
1932
$BODY1$
1933
SELECT * FROM $$||view_qual_name||$$
1934
ORDER BY sort_col
1935
LIMIT $1 OFFSET $2
1936
$BODY1$
1937
  LANGUAGE sql STABLE
1938
  COST 100
1939
  ROWS 1000
1940
$$;
1941
1942
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1943
END;
1944
$_$;
1945
1946
1947
--
1948 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1949
--
1950
1951
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1952
    LANGUAGE plpgsql STRICT
1953
    AS $_$
1954 10990 aaronmk
DECLARE
1955
	view_qual_name text = util.qual_name(view_);
1956
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1957 8325 aaronmk
BEGIN
1958
	EXECUTE $$
1959 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1960
  RETURNS integer AS
1961
$BODY1$
1962
SELECT $$||quote_ident(row_num_col)||$$
1963
FROM $$||view_qual_name||$$
1964
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1965
LIMIT 1
1966
$BODY1$
1967
  LANGUAGE sql STABLE
1968
  COST 100;
1969
$$;
1970
1971
	EXECUTE $$
1972 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1973
  RETURNS SETOF $$||view_||$$ AS
1974
$BODY1$
1975 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
1976
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1977
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1978
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1979 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
1980 8325 aaronmk
$BODY1$
1981
  LANGUAGE sql STABLE
1982
  COST 100
1983
  ROWS 1000
1984
$$;
1985 11010 aaronmk
1986
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1987
END;
1988
$_$;
1989
1990
1991
--
1992
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1993
--
1994
1995
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1996
    LANGUAGE plpgsql STRICT
1997
    AS $_$
1998
DECLARE
1999
	view_qual_name text = util.qual_name(view_);
2000
BEGIN
2001 8326 aaronmk
	EXECUTE $$
2002
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2003
  RETURNS SETOF $$||view_||$$
2004
  SET enable_sort TO 'off'
2005
  AS
2006
$BODY1$
2007 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
2008 8326 aaronmk
$BODY1$
2009
  LANGUAGE sql STABLE
2010
  COST 100
2011
  ROWS 1000
2012
;
2013
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2014
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2015
If you want to run EXPLAIN and get expanded output, use the regular subset
2016
function instead. (When a config param is set on a function, EXPLAIN produces
2017
just a function scan.)
2018
';
2019
$$;
2020 8325 aaronmk
END;
2021
$_$;
2022
2023
2024
--
2025 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2026
--
2027
2028 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2029
creates subset function which turns off enable_sort
2030
';
2031 11010 aaronmk
2032
2033
--
2034 12271 aaronmk
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2035
--
2036
2037
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2038
    LANGUAGE sql IMMUTABLE
2039
    AS $_$
2040
SELECT util.mk_set_search_path(util.schema_esc($1))
2041
$_$;
2042
2043
2044
--
2045 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2046
--
2047
2048
CREATE FUNCTION name(table_ regclass) RETURNS text
2049
    LANGUAGE sql STABLE
2050
    AS $_$
2051
SELECT relname::text FROM pg_class WHERE oid = $1
2052
$_$;
2053
2054
2055
--
2056 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2057 8083 aaronmk
--
2058
2059
CREATE FUNCTION name(type regtype) RETURNS text
2060 8097 aaronmk
    LANGUAGE sql STABLE STRICT
2061 8083 aaronmk
    AS $_$
2062
SELECT typname::text FROM pg_type WHERE oid = $1
2063
$_$;
2064
2065
2066
--
2067 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2068
--
2069
2070
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2071
    LANGUAGE sql IMMUTABLE
2072
    AS $_$
2073 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2074 9958 aaronmk
$_$;
2075
2076
2077
--
2078 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2079
--
2080
2081
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2082 9957 aaronmk
    LANGUAGE sql IMMUTABLE
2083 9956 aaronmk
    AS $_$
2084
SELECT $1 IS NOT NULL
2085
$_$;
2086
2087
2088
--
2089 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2090
--
2091
2092
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2093
    LANGUAGE sql IMMUTABLE
2094
    AS $_$
2095
SELECT util.hstore($1, NULL) || '*=>*'
2096
$_$;
2097
2098
2099
--
2100
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2101
--
2102
2103 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2104
for use with _map()
2105
';
2106 10373 aaronmk
2107
2108
--
2109 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2110 10984 aaronmk
--
2111
2112 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2113 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2114
    AS $_$
2115 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2116 10984 aaronmk
$_$;
2117
2118
2119
--
2120 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2121
--
2122
2123
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2124
    LANGUAGE sql IMMUTABLE
2125
    AS $_$
2126
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2127
$_$;
2128
2129
2130
--
2131 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2132
--
2133
2134
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2135 12267 aaronmk
    LANGUAGE sql STABLE STRICT
2136
    SET search_path TO pg_temp
2137 10988 aaronmk
    AS $_$
2138 12267 aaronmk
SELECT $1::text
2139 10988 aaronmk
$_$;
2140
2141
2142
--
2143 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2144
--
2145
2146
CREATE FUNCTION qual_name(type regtype) RETURNS text
2147
    LANGUAGE sql STABLE STRICT
2148
    SET search_path TO pg_temp
2149
    AS $_$
2150
SELECT $1::text
2151
$_$;
2152
2153
2154
--
2155
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2156
--
2157
2158
COMMENT ON FUNCTION qual_name(type regtype) IS '
2159
a type''s schema-qualified name
2160
';
2161
2162
2163
--
2164 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2165
--
2166
2167
CREATE FUNCTION qual_name(type unknown) RETURNS text
2168
    LANGUAGE sql STABLE STRICT
2169
    AS $_$
2170
SELECT util.qual_name($1::text::regtype)
2171
$_$;
2172
2173
2174
--
2175 12311 aaronmk
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2176
--
2177
2178
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2179
    LANGUAGE sql IMMUTABLE STRICT
2180
    AS $_$
2181
SELECT util.raise_notice('ERROR:  '||$1)
2182
$_$;
2183
2184
2185
--
2186 12249 aaronmk
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2187
--
2188
2189
CREATE FUNCTION raise_notice(msg text) RETURNS void
2190
    LANGUAGE plpgsql IMMUTABLE STRICT
2191
    AS $$
2192
BEGIN
2193
	RAISE NOTICE '%', msg;
2194
END;
2195
$$;
2196
2197
2198
--
2199 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2200
--
2201
2202
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2203
    LANGUAGE plpgsql IMMUTABLE STRICT
2204
    AS $$
2205
BEGIN
2206
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2207
END;
2208
$$;
2209
2210
2211
--
2212 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2213
--
2214
2215
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2216
    LANGUAGE sql IMMUTABLE
2217
    AS $_$
2218
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2219
$_$;
2220
2221
2222
--
2223 12333 aaronmk
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2224
--
2225
2226
CREATE FUNCTION regexp_quote(str text) RETURNS text
2227
    LANGUAGE sql IMMUTABLE
2228
    AS $_$
2229
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2230
$_$;
2231
2232
2233
--
2234 12340 aaronmk
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2235 12339 aaronmk
--
2236
2237 12340 aaronmk
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2238 12339 aaronmk
    LANGUAGE sql IMMUTABLE
2239
    AS $_$
2240
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2241
$_$;
2242
2243
2244
--
2245 12293 aaronmk
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2246
--
2247
2248
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2249
    LANGUAGE sql
2250
    AS $_$
2251
/* can't have in_table/out_table inherit from *each other*, because inheritance
2252
also causes the rows of the parent table to be included in the child table.
2253
instead, they need to inherit from a common, empty table. */
2254
SELECT util.drop_table($4, force := true);
2255
SELECT util.copy_struct($2, $4);
2256
SELECT util.inherit($2, $4);
2257
SELECT util.inherit($3, $4);
2258
2259
SELECT util.rematerialize_query($1, $$
2260
SELECT * FROM util.diff(
2261 12297 aaronmk
  $$||quote_nullable($2)||$$::regclass
2262
, $$||quote_nullable($3)||$$::regclass
2263 12293 aaronmk
, NULL::$$||$4||$$)
2264
$$);
2265 12303 aaronmk
2266
/* the table unfortunately cannot be *materialized* in human-readable form,
2267
because this would create column name collisions between the two sides */
2268
SELECT util.set_comment($1, '
2269
to view this table in human-readable form (with each side''s tuple column
2270
expanded to its component fields):
2271
SELECT (left_).*, (right_).* FROM '||$1||';
2272
');
2273 12293 aaronmk
$_$;
2274
2275
2276
--
2277
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2278
--
2279
2280
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2281
type_table (*required*): table to create as the shared base type
2282
';
2283
2284
2285
--
2286 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2287
--
2288
2289
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2290
    LANGUAGE sql
2291
    AS $_$
2292
SELECT util.drop_table($1);
2293
SELECT util.materialize_query($1, $2);
2294
$_$;
2295
2296
2297
--
2298
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2299
--
2300
2301
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2302
idempotent, but repeats action each time
2303
';
2304
2305
2306
--
2307 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2308
--
2309
2310 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2311 12247 aaronmk
    LANGUAGE sql
2312
    AS $_$
2313
SELECT util.drop_table($1);
2314
SELECT util.materialize_view($1, $2);
2315
$_$;
2316
2317
2318
--
2319 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2320 12247 aaronmk
--
2321
2322 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2323 12247 aaronmk
idempotent, but repeats action each time
2324
';
2325
2326
2327
--
2328 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2329 8137 aaronmk
--
2330
2331 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2332 8137 aaronmk
    LANGUAGE sql STRICT
2333
    AS $_$
2334 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2335 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2336 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
2337
SELECT NULL::void; -- don't fold away functions called in previous query
2338 8137 aaronmk
$_$;
2339
2340
2341
--
2342 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2343 8137 aaronmk
--
2344
2345 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2346
idempotent
2347
';
2348 8137 aaronmk
2349
2350
--
2351 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2352
--
2353
2354
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2355
    LANGUAGE sql STRICT
2356
    AS $_$
2357 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2358
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2359 10297 aaronmk
SELECT util.set_col_names($1, $2);
2360
$_$;
2361
2362
2363
--
2364
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2365
--
2366
2367 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2368
idempotent.
2369
alters the names table, so it will need to be repopulated after running this function.
2370
';
2371 10297 aaronmk
2372
2373
--
2374 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2375 8143 aaronmk
--
2376
2377
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2378
    LANGUAGE sql STRICT
2379
    AS $_$
2380 10152 aaronmk
SELECT util.drop_table($1);
2381 8183 aaronmk
SELECT util.mk_map_table($1);
2382 8143 aaronmk
$_$;
2383
2384
2385
--
2386 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2387
--
2388
2389
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2390
    LANGUAGE plpgsql STRICT
2391
    AS $_$
2392
DECLARE
2393
	result text = NULL;
2394
BEGIN
2395
	BEGIN
2396
		result = util.show_create_view(view_);
2397
		PERFORM util.eval($$DROP VIEW $$||view_);
2398
	EXCEPTION
2399
		WHEN undefined_table THEN NULL;
2400
	END;
2401
	RETURN result;
2402
END;
2403
$_$;
2404
2405
2406
--
2407 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2408
--
2409
2410
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2411
    LANGUAGE sql
2412
    AS $_$
2413 12269 aaronmk
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2414 11660 aaronmk
$_$;
2415
2416
2417
--
2418 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2419
--
2420
2421
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2422
    LANGUAGE sql STABLE
2423
    AS $_$
2424
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2425
$_$;
2426
2427
2428
--
2429 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2430
--
2431
2432
CREATE FUNCTION schema(table_ regclass) RETURNS text
2433
    LANGUAGE sql STABLE
2434
    AS $_$
2435 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2436 12242 aaronmk
$_$;
2437
2438
2439
--
2440 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2441
--
2442
2443
CREATE FUNCTION schema(type regtype) RETURNS text
2444
    LANGUAGE sql STABLE
2445
    AS $_$
2446 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2447 10794 aaronmk
$_$;
2448
2449
2450
--
2451
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2452
--
2453
2454
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2455
    LANGUAGE sql STABLE
2456
    AS $_$
2457
SELECT util.schema(pg_typeof($1))
2458
$_$;
2459
2460
2461
--
2462 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2463
--
2464
2465
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2466
    LANGUAGE sql STABLE
2467
    AS $_$
2468
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2469
$_$;
2470
2471
2472
--
2473 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2474
--
2475
2476 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2477
a schema bundle is a group of schemas with a common prefix
2478
';
2479 12135 aaronmk
2480
2481
--
2482
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2483
--
2484
2485
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2486
    LANGUAGE sql
2487
    AS $_$
2488
SELECT util.schema_rename(old_schema,
2489
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2490
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2491
SELECT NULL::void; -- don't fold away functions called in previous query
2492
$_$;
2493
2494
2495
--
2496
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2497
--
2498
2499
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2500
    LANGUAGE plpgsql
2501
    AS $$
2502
BEGIN
2503
	-- don't schema_bundle_rm() the schema_bundle to keep!
2504
	IF replace = with_ THEN RETURN; END IF;
2505
2506
	PERFORM util.schema_bundle_rm(replace);
2507
	PERFORM util.schema_bundle_rename(with_, replace);
2508
END;
2509
$$;
2510
2511
2512
--
2513
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2514
--
2515
2516
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2517
    LANGUAGE sql
2518
    AS $_$
2519
SELECT util.schema_rm(schema)
2520
FROM util.schema_bundle_get_schemas($1) f (schema);
2521
SELECT NULL::void; -- don't fold away functions called in previous query
2522
$_$;
2523
2524
2525
--
2526 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2527 10795 aaronmk
--
2528
2529 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2530 10795 aaronmk
    LANGUAGE sql STABLE
2531
    AS $_$
2532
SELECT quote_ident(util.schema($1))
2533
$_$;
2534
2535
2536
--
2537 12324 aaronmk
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2538
--
2539
2540
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2541 12334 aaronmk
    LANGUAGE sql IMMUTABLE
2542 12324 aaronmk
    AS $_$
2543
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2544
$_$;
2545
2546
2547
--
2548 12304 aaronmk
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2549
--
2550
2551
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2552
    LANGUAGE sql STABLE
2553
    AS $_$
2554
SELECT oid FROM pg_namespace WHERE nspname = $1
2555
$_$;
2556
2557
2558
--
2559 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2560
--
2561
2562
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2563
    LANGUAGE sql
2564
    AS $_$
2565
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2566
$_$;
2567
2568
2569
--
2570 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2571
--
2572
2573
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2574
    LANGUAGE plpgsql
2575
    AS $$
2576
BEGIN
2577
	-- don't schema_rm() the schema to keep!
2578
	IF replace = with_ THEN RETURN; END IF;
2579
2580
	PERFORM util.schema_rm(replace);
2581
	PERFORM util.schema_rename(with_, replace);
2582
END;
2583
$$;
2584
2585
2586
--
2587 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2588
--
2589
2590
CREATE FUNCTION schema_rm(schema text) RETURNS void
2591
    LANGUAGE sql
2592
    AS $_$
2593
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2594
$_$;
2595
2596
2597
--
2598 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2599
--
2600
2601
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2602
    LANGUAGE sql STRICT
2603
    AS $_$
2604
SELECT util.eval(
2605
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2606
$_$;
2607
2608
2609
--
2610 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2611 8153 aaronmk
--
2612
2613
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2614
    LANGUAGE plpgsql STRICT
2615
    AS $_$
2616
DECLARE
2617 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
2618
    new text[] = ARRAY(SELECT util.map_values(names));
2619 8153 aaronmk
BEGIN
2620
    old = old[1:array_length(new, 1)]; -- truncate to same length
2621 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2622
||$$ TO $$||quote_ident(value))
2623 10149 aaronmk
    FROM each(hstore(old, new))
2624
    WHERE value != key -- not same name
2625
    ;
2626 8153 aaronmk
END;
2627
$_$;
2628
2629
2630
--
2631 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2632 8153 aaronmk
--
2633
2634 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2635
idempotent
2636
';
2637 8153 aaronmk
2638
2639
--
2640 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2641
--
2642
2643
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2644
    LANGUAGE plpgsql STRICT
2645
    AS $_$
2646
DECLARE
2647
	row_ util.map;
2648
BEGIN
2649 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
2650
	BEGIN
2651
		PERFORM util.set_col_names(table_, names);
2652
	EXCEPTION
2653
		WHEN array_subscript_error THEN -- selective suppress
2654
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2655
				-- metadata cols not yet added
2656
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2657
			END IF;
2658
	END;
2659
2660 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2661 10145 aaronmk
	LOOP
2662 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
2663
			substring(row_."from" from 2));
2664 10145 aaronmk
	END LOOP;
2665
2666
	PERFORM util.set_col_names(table_, names);
2667
END;
2668
$_$;
2669
2670
2671
--
2672
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2673
--
2674
2675 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2676
idempotent.
2677
the metadata mappings must be *last* in the names table.
2678
';
2679 10145 aaronmk
2680
2681
--
2682 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2683 8107 aaronmk
--
2684
2685
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2686
    LANGUAGE plpgsql STRICT
2687
    AS $_$
2688
DECLARE
2689
    sql text = $$ALTER TABLE $$||table_||$$
2690
$$||NULLIF(array_to_string(ARRAY(
2691
    SELECT
2692
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2693
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2694
    FROM
2695
    (
2696
        SELECT
2697
          quote_ident(col_name) AS col_name_sql
2698 8183 aaronmk
        , util.col_type((table_, col_name)) AS curr_type
2699 8107 aaronmk
        , type AS target_type
2700
        FROM unnest(col_casts)
2701
    ) s
2702
    WHERE curr_type != target_type
2703
), '
2704
, '), '');
2705
BEGIN
2706 12251 aaronmk
    PERFORM util.debug_print_sql(sql);
2707 8107 aaronmk
    EXECUTE COALESCE(sql, '');
2708
END;
2709
$_$;
2710
2711
2712
--
2713 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2714 8107 aaronmk
--
2715
2716 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2717
idempotent
2718
';
2719 8107 aaronmk
2720
2721
--
2722 12302 aaronmk
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2723
--
2724
2725
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
2726
    LANGUAGE sql STRICT
2727
    AS $_$
2728
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
2729
$_$;
2730
2731
2732
--
2733 11651 aaronmk
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2734
--
2735
2736
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2737
    LANGUAGE sql STABLE
2738
    AS $_$
2739 11656 aaronmk
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2740
$$||util.show_grants_for($1)
2741 11651 aaronmk
$_$;
2742
2743
2744
--
2745 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2746
--
2747
2748
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2749
    LANGUAGE sql STABLE
2750
    AS $_$
2751 12269 aaronmk
SELECT string_agg(cmd, '')
2752 11655 aaronmk
FROM
2753
(
2754
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2755
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2756
$$ ELSE '' END) AS cmd
2757
	FROM util.grants_users() f (user_)
2758
) s
2759
$_$;
2760
2761
2762
--
2763 12325 aaronmk
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
2764
--
2765
2766
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
2767
    LANGUAGE sql STABLE
2768
    AS $_$
2769
SELECT oid FROM pg_class
2770
WHERE relkind = ANY($3) AND relname ~ $1
2771
AND util.schema_matches(util.schema(relnamespace), $2)
2772
ORDER BY relname
2773
$_$;
2774
2775
2776
--
2777 12305 aaronmk
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
2778
--
2779
2780 12326 aaronmk
CREATE FUNCTION show_views_like(name_regexp text, schema text) RETURNS SETOF regclass
2781 12305 aaronmk
    LANGUAGE sql STABLE
2782
    AS $_$
2783 12328 aaronmk
SELECT view_
2784
FROM util.show_relations_like($1, types := ARRAY['v']) view_
2785
WHERE util.schema(view_) = $2
2786 12305 aaronmk
$_$;
2787
2788
2789
--
2790 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2791 8144 aaronmk
--
2792
2793
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2794 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
2795 8144 aaronmk
    AS $_$
2796
DECLARE
2797
    hstore hstore;
2798
BEGIN
2799
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2800
        table_||$$))$$ INTO STRICT hstore;
2801
    RETURN hstore;
2802
END;
2803
$_$;
2804
2805
2806
--
2807 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2808
--
2809
2810
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2811
    LANGUAGE sql STABLE STRICT
2812
    AS $_$
2813
SELECT COUNT(*) > 0 FROM pg_constraint
2814
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2815
$_$;
2816
2817
2818
--
2819
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2820
--
2821
2822 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
2823
gets whether a status flag is set by the presence of a table constraint
2824
';
2825 10184 aaronmk
2826
2827
--
2828 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2829
--
2830
2831
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2832
    LANGUAGE sql STRICT
2833
    AS $_$
2834
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2835
||quote_ident($2)||$$ CHECK (true)$$)
2836
$_$;
2837
2838
2839
--
2840
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2841
--
2842
2843 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2844
stores a status flag by the presence of a table constraint.
2845
idempotent.
2846
';
2847 10182 aaronmk
2848
2849
--
2850 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2851
--
2852
2853
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2854
    LANGUAGE sql STABLE STRICT
2855
    AS $_$
2856
SELECT util.table_flag__get($1, 'nulls_mapped')
2857
$_$;
2858
2859
2860
--
2861
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2862
--
2863
2864 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
2865
gets whether a table''s NULL-equivalent strings have been replaced with NULL
2866
';
2867 10185 aaronmk
2868
2869
--
2870 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2871
--
2872
2873
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2874
    LANGUAGE sql STRICT
2875
    AS $_$
2876
SELECT util.table_flag__set($1, 'nulls_mapped')
2877
$_$;
2878
2879
2880
--
2881
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2882
--
2883
2884 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2885
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2886
idempotent.
2887
';
2888 10183 aaronmk
2889
2890
--
2891 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2892 8088 aaronmk
--
2893
2894
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2895
    LANGUAGE plpgsql STRICT
2896
    AS $_$
2897
DECLARE
2898
    row record;
2899
BEGIN
2900 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2901 8088 aaronmk
    LOOP
2902
        IF row.global_name != row.name THEN
2903
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2904
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2905
        END IF;
2906
    END LOOP;
2907
END;
2908
$_$;
2909
2910
2911
--
2912 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2913 8088 aaronmk
--
2914
2915 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2916
idempotent
2917
';
2918 8088 aaronmk
2919
2920
--
2921 10365 aaronmk
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2922
--
2923
2924
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2925
    LANGUAGE sql STRICT
2926
    AS $_$
2927 10595 aaronmk
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2928 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
2929
$_$;
2930
2931
2932
--
2933
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2934
--
2935
2936 12235 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2937
trims table_ to include only columns in the original data.
2938
idempotent.
2939
';
2940 10365 aaronmk
2941
2942
--
2943 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2944 8142 aaronmk
--
2945
2946
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2947
    LANGUAGE plpgsql STRICT
2948
    AS $_$
2949
BEGIN
2950
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2951
END;
2952
$_$;
2953
2954
2955
--
2956 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2957 8142 aaronmk
--
2958
2959 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2960
idempotent
2961
';
2962 8142 aaronmk
2963
2964
--
2965 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2966
--
2967
2968
CREATE FUNCTION try_create(sql text) RETURNS void
2969
    LANGUAGE plpgsql STRICT
2970
    AS $$
2971
BEGIN
2972 10146 aaronmk
    PERFORM util.eval(sql);
2973 8199 aaronmk
EXCEPTION
2974 10071 aaronmk
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2975 8199 aaronmk
    WHEN undefined_column THEN NULL;
2976
    WHEN duplicate_column THEN NULL;
2977
END;
2978
$$;
2979
2980
2981
--
2982
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2983
--
2984
2985 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
2986
idempotent
2987
';
2988 8199 aaronmk
2989
2990
--
2991 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2992
--
2993
2994
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2995
    LANGUAGE sql STRICT
2996
    AS $_$
2997
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2998
$_$;
2999
3000
3001
--
3002
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3003
--
3004
3005 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3006
idempotent
3007
';
3008 8209 aaronmk
3009
3010
--
3011 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3012
--
3013
3014
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3015
    LANGUAGE sql IMMUTABLE
3016
    AS $_$
3017
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3018
$_$;
3019
3020
3021
--
3022 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3023
--
3024
3025 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3026
a type''s NOT NULL qualifier
3027
';
3028 10161 aaronmk
3029
3030
--
3031 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3032
--
3033
3034 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3035
    LANGUAGE plpgsql STABLE
3036 8185 aaronmk
    AS $_$
3037
DECLARE
3038
    type regtype;
3039
BEGIN
3040 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3041
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3042 8185 aaronmk
    RETURN type;
3043
END;
3044
$_$;
3045
3046
3047
--
3048 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3049
--
3050
3051
CREATE AGGREGATE all_same(anyelement) (
3052
    SFUNC = all_same_transform,
3053
    STYPE = anyarray,
3054
    FINALFUNC = all_same_final
3055
);
3056
3057
3058
--
3059
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3060
--
3061
3062 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
3063
includes NULLs in comparison
3064
';
3065 9959 aaronmk
3066
3067
--
3068 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3069 2595 aaronmk
--
3070
3071
CREATE AGGREGATE join_strs(text, text) (
3072 4052 aaronmk
    SFUNC = join_strs_transform,
3073 4010 aaronmk
    STYPE = text
3074 2595 aaronmk
);
3075
3076
3077 8147 aaronmk
--
3078 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3079 8147 aaronmk
--
3080
3081
CREATE OPERATOR -> (
3082
    PROCEDURE = map_get,
3083
    LEFTARG = regclass,
3084
    RIGHTARG = text
3085
);
3086
3087
3088 10308 aaronmk
--
3089
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3090
--
3091
3092
CREATE OPERATOR => (
3093
    PROCEDURE = hstore,
3094 10357 aaronmk
    LEFTARG = text[],
3095 10608 aaronmk
    RIGHTARG = text
3096 10308 aaronmk
);
3097
3098
3099
--
3100 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3101 10308 aaronmk
--
3102
3103 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
3104
usage: array[''key1'', ...]::text[] => ''value''
3105
';
3106 10308 aaronmk
3107
3108 10391 aaronmk
--
3109 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3110
--
3111
3112
CREATE OPERATOR ?*>= (
3113
    PROCEDURE = is_populated_more_often_than,
3114
    LEFTARG = anyelement,
3115
    RIGHTARG = anyelement
3116
);
3117
3118
3119
--
3120 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3121
--
3122
3123
CREATE OPERATOR ?>= (
3124
    PROCEDURE = is_more_complete_than,
3125
    LEFTARG = anyelement,
3126
    RIGHTARG = anyelement
3127
);
3128
3129
3130 11005 aaronmk
--
3131
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3132
--
3133
3134
CREATE OPERATOR ||% (
3135
    PROCEDURE = concat_esc,
3136
    LEFTARG = text,
3137
    RIGHTARG = text
3138
);
3139
3140
3141
--
3142
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3143
--
3144
3145 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
3146
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3147
';
3148 11005 aaronmk
3149
3150 2107 aaronmk
--
3151 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
3152 8140 aaronmk
--
3153
3154
CREATE TABLE map (
3155
    "from" text NOT NULL,
3156 8158 aaronmk
    "to" text,
3157
    filter text,
3158
    notes text
3159 8140 aaronmk
);
3160
3161
3162
--
3163 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3164
--
3165
3166
3167
3168
--
3169 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3170 8140 aaronmk
--
3171
3172
3173
3174
--
3175 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3176 8140 aaronmk
--
3177
3178
ALTER TABLE ONLY map
3179 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3180 8140 aaronmk
3181
3182
--
3183 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
3184
--
3185
3186
ALTER TABLE ONLY map
3187
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3188
3189
3190
--
3191 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3192
--
3193
3194
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3195
3196
3197
--
3198 2136 aaronmk
-- PostgreSQL database dump complete
3199
--