Project

General

Profile

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