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