Project

General

Profile

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