Project

General

Profile

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