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