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 12447 aaronmk
NOTE: 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. avoiding use of STRICT also makes functions *much* easier to troubleshoot, because they won''t mysteriously do nothing if called with only NULL arguments, even when you have added debug-print statements.
27 12235 aaronmk
';
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 12423 aaronmk
-- Name: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77
78
CREATE FUNCTION "%=="(left_ anyelement, right_ anyelement) RETURNS boolean
79 12443 aaronmk
    LANGUAGE sql STABLE
80 12423 aaronmk
    AS $_$
81 12436 aaronmk
SELECT keys($1) = keys($2)
82 12423 aaronmk
$_$;
83
84
85
--
86 12443 aaronmk
-- Name: FUNCTION "%=="(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
87
--
88
89
COMMENT ON FUNCTION "%=="(left_ anyelement, right_ anyelement) IS '
90
needs to be declared STABLE instead of IMMUTABLE because it depends on the search_path (as described at http://vegpath.org/links/#PostgreSQL:%20Documentation:%209.3:%20Function%20Volatility%20Categories%20**)
91
';
92
93
94
--
95 8183 aaronmk
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
96 2596 aaronmk
--
97
98 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
99 3422 aaronmk
    LANGUAGE sql IMMUTABLE
100
    AS $_$
101 4501 aaronmk
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
102 3422 aaronmk
$_$;
103
104
105
--
106 8183 aaronmk
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
107 5937 aaronmk
--
108
109 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
110 5937 aaronmk
    LANGUAGE sql IMMUTABLE
111
    AS $_$
112
SELECT bool_and(value)
113
FROM
114
(VALUES
115
      ($1)
116
    , ($2)
117 5956 aaronmk
    , ($3)
118
    , ($4)
119
    , ($5)
120 5937 aaronmk
)
121
AS v (value)
122
$_$;
123
124
125
--
126 8183 aaronmk
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
127 5937 aaronmk
--
128
129 12235 aaronmk
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
130
_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.
131
';
132 5937 aaronmk
133
134
--
135 8183 aaronmk
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
136 7704 aaronmk
--
137
138
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
139
    LANGUAGE sql IMMUTABLE
140
    AS $_$
141
SELECT avg(value)
142
FROM
143
(VALUES
144
      ($1)
145
    , ($2)
146
    , ($3)
147
    , ($4)
148
    , ($5)
149
)
150
AS v (value)
151
$_$;
152
153
154
--
155 8183 aaronmk
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
156 7679 aaronmk
--
157
158
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
159 12441 aaronmk
    LANGUAGE sql IMMUTABLE
160 7679 aaronmk
    AS $_$
161 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)
162 7698 aaronmk
FROM
163
(
164
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
165
    UNION ALL
166 7702 aaronmk
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
167
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
168 7698 aaronmk
)
169
matches (g)
170 7679 aaronmk
$_$;
171
172
173
--
174 8183 aaronmk
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
175 7672 aaronmk
--
176
177 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
178 7672 aaronmk
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180 8183 aaronmk
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
181 7672 aaronmk
FROM
182
(VALUES
183 7677 aaronmk
      ($1)
184 7672 aaronmk
    , ($2/60)
185
    , ($3/60/60)
186
)
187
AS v (value)
188
$_$;
189
190
191
--
192 8183 aaronmk
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
193 7723 aaronmk
--
194
195
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
196
    LANGUAGE sql IMMUTABLE
197
    AS $_$
198 8183 aaronmk
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
199 7723 aaronmk
$_$;
200
201
202
--
203 8183 aaronmk
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
204 4142 aaronmk
--
205
206
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
207
    LANGUAGE sql IMMUTABLE
208
    AS $_$
209
SELECT $1 = $2
210
$_$;
211
212
213
--
214 8183 aaronmk
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
215 7396 aaronmk
--
216
217
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
218
    LANGUAGE sql IMMUTABLE
219
    AS $_$
220
-- Fix dates after threshold date
221
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
222
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
223
$_$;
224
225
226
--
227 8183 aaronmk
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
228 4147 aaronmk
--
229
230
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
231
    LANGUAGE sql IMMUTABLE
232
    AS $_$
233
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
234
$_$;
235
236
237
--
238 8183 aaronmk
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
239 4147 aaronmk
--
240
241
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
242
    LANGUAGE sql IMMUTABLE
243
    AS $_$
244 8183 aaronmk
SELECT util._if($1 != '', $2, $3)
245 4147 aaronmk
$_$;
246
247
248
--
249 10699 aaronmk
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
250 4325 aaronmk
--
251
252 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
253 4325 aaronmk
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255 7848 aaronmk
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
256 4325 aaronmk
$_$;
257
258
259
--
260 10699 aaronmk
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
261 5009 aaronmk
--
262
263 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
264 5009 aaronmk
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266 7848 aaronmk
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
267 5009 aaronmk
$_$;
268
269
270
--
271 13355 aaronmk
-- Name: _km_to_m(double precision); Type: FUNCTION; Schema: util; Owner: -
272
--
273
274
CREATE FUNCTION _km_to_m(value double precision) RETURNS double precision
275
    LANGUAGE sql IMMUTABLE
276
    AS $_$
277
SELECT $1*1000.
278
$_$;
279
280
281
--
282 10699 aaronmk
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
283 3422 aaronmk
--
284
285 10699 aaronmk
CREATE FUNCTION _label(label text, value text) RETURNS text
286 4682 aaronmk
    LANGUAGE sql IMMUTABLE
287
    AS $_$
288
SELECT coalesce($1 || ': ', '') || $2
289
$_$;
290 2596 aaronmk
291
292
--
293 8825 aaronmk
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
294
--
295
296
CREATE FUNCTION _lowercase(value text) RETURNS text
297 10388 aaronmk
    LANGUAGE sql IMMUTABLE
298 8825 aaronmk
    AS $_$
299
SELECT lower($1)
300
$_$;
301
302
303
--
304 11667 aaronmk
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
305
--
306
307
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
308
    LANGUAGE plpgsql IMMUTABLE STRICT
309
    AS $$
310
DECLARE
311
    result value%TYPE := util._map(map, value::text)::unknown;
312
BEGIN
313
    RETURN result;
314
END;
315
$$;
316
317
318
--
319 8183 aaronmk
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
320 6222 aaronmk
--
321
322
CREATE FUNCTION _map(map hstore, value text) RETURNS text
323 7820 aaronmk
    LANGUAGE plpgsql IMMUTABLE STRICT
324 6222 aaronmk
    AS $$
325
DECLARE
326 6271 aaronmk
    match text := map -> value;
327 6222 aaronmk
BEGIN
328 6271 aaronmk
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
329
        match := map -> '*'; -- use default entry
330
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
331
        END IF;
332
    END IF;
333
334
    -- Interpret result
335 6243 aaronmk
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
336
    ELSIF match = '*' THEN RETURN value;
337
    ELSE RETURN match;
338 6222 aaronmk
    END IF;
339
END;
340
$$;
341
342
343
--
344 8183 aaronmk
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
345 5408 aaronmk
--
346
347
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
348
    LANGUAGE sql IMMUTABLE
349
    AS $_$
350 7289 aaronmk
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
351 5408 aaronmk
$_$;
352
353
354
--
355 8183 aaronmk
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
356 2940 aaronmk
--
357
358 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
359 2940 aaronmk
    LANGUAGE sql IMMUTABLE
360
    AS $_$
361 8183 aaronmk
SELECT util.join_strs(value, '; ')
362 2940 aaronmk
FROM
363
(
364
    SELECT *
365
    FROM
366
    (
367
        SELECT
368
        DISTINCT ON (value)
369
        *
370
        FROM
371
        (VALUES
372 4012 aaronmk
              (1, $1)
373
            , (2, $2)
374
            , (3, $3)
375
            , (4, $4)
376
            , (5, $5)
377
            , (6, $6)
378
            , (7, $7)
379
            , (8, $8)
380
            , (9, $9)
381
            , (10, $10)
382 2940 aaronmk
        )
383
        AS v (sort_order, value)
384 4011 aaronmk
        WHERE value IS NOT NULL
385 2940 aaronmk
    )
386
    AS v
387
    ORDER BY sort_order
388
)
389
AS v
390
$_$;
391
392
393
--
394 8183 aaronmk
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
395 7140 aaronmk
--
396
397
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
398
    LANGUAGE sql IMMUTABLE
399
    AS $_$
400
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
401
$_$;
402
403
404
--
405 8183 aaronmk
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
406 6354 aaronmk
--
407
408
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
409
    LANGUAGE sql IMMUTABLE
410
    AS $_$
411 8183 aaronmk
SELECT util.join_strs(value, ' ')
412 6354 aaronmk
FROM
413
(
414
    SELECT *
415
    FROM
416
    (
417
        SELECT
418
        DISTINCT ON (value)
419
        *
420
        FROM
421
        (VALUES
422
              (1, $1)
423
            , (2, $2)
424
            , (3, $3)
425
            , (4, $4)
426
            , (5, $5)
427
            , (6, $6)
428
            , (7, $7)
429
            , (8, $8)
430
            , (9, $9)
431
            , (10, $10)
432
        )
433
        AS v (sort_order, value)
434
        WHERE value IS NOT NULL
435
    )
436
    AS v
437
    ORDER BY sort_order
438
)
439
AS v
440
$_$;
441
442
443
--
444 8183 aaronmk
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
445 5408 aaronmk
--
446
447
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
448
    LANGUAGE sql IMMUTABLE
449
    AS $_$
450 7289 aaronmk
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
451 5408 aaronmk
$_$;
452
453
454
--
455 8183 aaronmk
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
456 6316 aaronmk
--
457
458
CREATE FUNCTION _not(value boolean) RETURNS boolean
459 10388 aaronmk
    LANGUAGE sql IMMUTABLE
460 6316 aaronmk
    AS $_$
461
SELECT NOT $1
462
$_$;
463
464
465
--
466 8183 aaronmk
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
467 7104 aaronmk
--
468
469
CREATE FUNCTION _now() RETURNS timestamp with time zone
470
    LANGUAGE sql STABLE
471
    AS $$
472
SELECT now()
473
$$;
474
475
476
--
477 11667 aaronmk
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
478
--
479
480
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
481
    LANGUAGE sql IMMUTABLE
482
    AS $_$
483
SELECT util."_nullIf"($1, $2, $3::util.datatype)
484
$_$;
485
486
487
--
488 8183 aaronmk
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
489 2949 aaronmk
--
490
491 4475 aaronmk
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
492 2949 aaronmk
    LANGUAGE plpgsql IMMUTABLE
493
    AS $$
494
DECLARE
495 8183 aaronmk
    type util.datatype NOT NULL := type; -- add NOT NULL
496 2949 aaronmk
BEGIN
497 4475 aaronmk
    IF type = 'str' THEN RETURN nullif(value::text, "null");
498 2722 aaronmk
    -- Invalid value is ignored, but invalid null value generates error
499 2949 aaronmk
    ELSIF type = 'float' THEN
500 2722 aaronmk
        DECLARE
501
            -- Outside the try block so that invalid null value generates error
502 2949 aaronmk
            "null" double precision := "null"::double precision;
503 2722 aaronmk
        BEGIN
504 2949 aaronmk
            RETURN nullif(value::double precision, "null");
505 2722 aaronmk
        EXCEPTION
506 2949 aaronmk
            WHEN data_exception THEN RETURN value; -- ignore invalid value
507 2722 aaronmk
        END;
508 2610 aaronmk
    END IF;
509
END;
510
$$;
511
512
513
--
514 8183 aaronmk
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
515 6355 aaronmk
--
516
517
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
518
    LANGUAGE sql IMMUTABLE
519
    AS $_$
520
SELECT bool_or(value)
521
FROM
522
(VALUES
523
      ($1)
524
    , ($2)
525
    , ($3)
526
    , ($4)
527
    , ($5)
528
)
529
AS v (value)
530
$_$;
531
532
533
--
534 8183 aaronmk
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
535 6437 aaronmk
--
536
537 12235 aaronmk
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
538
_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.
539
';
540 6437 aaronmk
541
542
--
543 8183 aaronmk
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
544 7706 aaronmk
--
545
546
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
547
    LANGUAGE sql IMMUTABLE
548
    AS $_$
549
SELECT $2 - $1
550
$_$;
551
552
553
--
554 8183 aaronmk
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
555 6793 aaronmk
--
556
557
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
558 10388 aaronmk
    LANGUAGE sql IMMUTABLE
559 6793 aaronmk
    AS $_$
560
SELECT regexp_split_to_table($1, $2)
561
$_$;
562
563
564
--
565 10594 aaronmk
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
566
--
567
568
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
569 12446 aaronmk
    LANGUAGE sql STABLE
570 10594 aaronmk
    AS $_$
571
SELECT util.derived_cols($1, $2)
572
UNION
573
SELECT util.eval2set($$
574
SELECT col
575
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
576
JOIN $$||$2||$$ ON "to" = col
577
WHERE "from" LIKE ':%'
578
$$, NULL::text)
579
$_$;
580
581
582
--
583
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
584
--
585
586 12235 aaronmk
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
587
gets table_''s added columns (all the columns not in the original data)
588
';
589 10594 aaronmk
590
591
--
592 9959 aaronmk
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
593
--
594
595
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
596
    LANGUAGE sql IMMUTABLE
597
    AS $_$
598
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
599
$_$;
600
601
602
--
603
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
604
--
605
606
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
607
    LANGUAGE plpgsql IMMUTABLE
608
    AS $$
609
DECLARE
610
	value_cmp         state%TYPE = ARRAY[value];
611
	state             state%TYPE = COALESCE(state, value_cmp);
612
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
613
BEGIN
614
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
615
END;
616
$$;
617
618
619
--
620 12320 aaronmk
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
621
--
622
623
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
624
    LANGUAGE sql
625
    AS $_$
626
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
627
$_$;
628
629
630
--
631 12369 aaronmk
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
632
--
633
634
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
635 12446 aaronmk
    LANGUAGE sql
636 12369 aaronmk
    AS $_$
637
SELECT util.set_comment($1, concat(util.comment($1), $2))
638
$_$;
639
640
641
--
642
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
643
--
644
645
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
646
comment: must start and end with a newline
647
';
648
649
650
--
651 10305 aaronmk
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
652
--
653
654
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
655
    LANGUAGE sql IMMUTABLE
656
    AS $_$
657
SELECT pg_catalog.array_fill($1, ARRAY[$2])
658
$_$;
659
660
661
--
662 10303 aaronmk
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
663
--
664
665
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
666 10354 aaronmk
    LANGUAGE sql IMMUTABLE
667 10303 aaronmk
    AS $_$
668 10321 aaronmk
SELECT util.array_length($1, 1)
669 10303 aaronmk
$_$;
670
671
672
--
673 10304 aaronmk
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
674
--
675
676
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
677 10354 aaronmk
    LANGUAGE sql IMMUTABLE
678 10304 aaronmk
    AS $_$
679 10354 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
680 10304 aaronmk
$_$;
681
682
683
--
684
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
685
--
686
687 12235 aaronmk
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
688
returns 0 instead of NULL for empty arrays
689
';
690 10304 aaronmk
691
692
--
693 13453 aaronmk
-- Name: array_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
694
--
695
696
CREATE FUNCTION array_reverse("array" anyarray) RETURNS anyarray
697
    LANGUAGE sql IMMUTABLE
698
    AS $_$
699
SELECT array(SELECT * FROM util.in_reverse($1))
700
$_$;
701
702
703
--
704 12662 aaronmk
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
705 12655 aaronmk
--
706
707 12662 aaronmk
CREATE FUNCTION auto_rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
708 12655 aaronmk
    LANGUAGE sql
709
    AS $_$
710 12662 aaronmk
SELECT CASE WHEN util.freq_always_1($1, $2)
711 13097 aaronmk
THEN util.rm_freq($1, $2)
712 12685 aaronmk
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
713 12662 aaronmk
END
714 12655 aaronmk
$_$;
715
716
717
--
718 13134 aaronmk
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
719
--
720
721
CREATE FUNCTION "cast"(value text, ret_type_null anyelement) RETURNS anyelement
722
    LANGUAGE plpgsql IMMUTABLE
723
    AS $$
724
/* must use LANGUAGE plpgsql because LANGUAGE sql does not assignment-cast the
725
return value, causing a type mismatch */
726
BEGIN
727
	-- will then be assignment-cast to return type via INOUT
728
	RETURN value::cstring;
729
END;
730
$$;
731
732
733
--
734
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
735
--
736
737
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
738
allows casting to an arbitrary type without eval()
739
740
usage:
741
SELECT util.cast(''value'', NULL::integer);
742
743
note that there does *not* need to be a cast from text to the output type,
744
because an INOUT cast is used instead
745
(http://www.postgresql.org/docs/9.3/static/sql-createcast.html#AEN69507)
746
747
ret_type_null: NULL::ret_type
748
';
749
750
751
--
752 8183 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
753 8104 aaronmk
--
754
755
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
756 12446 aaronmk
    LANGUAGE sql STABLE
757 8104 aaronmk
    AS $_$
758
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
759
$_$;
760
761
762
--
763 8183 aaronmk
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
764 8105 aaronmk
--
765
766
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
767
    LANGUAGE plpgsql STRICT
768
    AS $_$
769
BEGIN
770
    -- not yet clustered (ARRAY[] compares NULLs literally)
771 8183 aaronmk
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
772 8105 aaronmk
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
773
    END IF;
774
END;
775
$_$;
776
777
778
--
779 8183 aaronmk
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
780 8105 aaronmk
--
781
782 12235 aaronmk
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
783
idempotent
784
';
785 8105 aaronmk
786
787
--
788 12683 aaronmk
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
789
--
790
791
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
792
    LANGUAGE sql IMMUTABLE
793
    AS $_$
794
SELECT value
795
FROM unnest($1) value
796
WHERE value IS NOT NULL
797
LIMIT 1
798
$_$;
799
800
801
--
802
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
803
--
804
805
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
806
uses:
807
* coalescing array elements or rows together
808
* forcing evaluation of all values of a COALESCE()
809
';
810
811
812
--
813 10986 aaronmk
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
814
--
815
816
CREATE FUNCTION col__min(col col_ref) RETURNS integer
817
    LANGUAGE sql STABLE
818
    AS $_$
819
SELECT util.eval2val($$
820
SELECT $$||quote_ident($1.name)||$$
821
FROM $$||$1.table_||$$
822
ORDER BY $$||quote_ident($1.name)||$$ ASC
823
LIMIT 1
824
$$, NULL::integer)
825
$_$;
826
827
828
--
829 10136 aaronmk
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
830
--
831
832
CREATE FUNCTION col_comment(col col_ref) RETURNS text
833
    LANGUAGE plpgsql STABLE STRICT
834
    AS $$
835
DECLARE
836
	comment text;
837
BEGIN
838
	SELECT description
839
	FROM pg_attribute
840
	LEFT JOIN pg_description ON objoid = attrelid
841
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
842
	WHERE attrelid = col.table_ AND attname = col.name
843
	INTO STRICT comment
844
	;
845
	RETURN comment;
846
EXCEPTION
847
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
848
END;
849
$$;
850
851
852
--
853 10130 aaronmk
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
854
--
855
856
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
857
    LANGUAGE plpgsql STABLE STRICT
858
    AS $$
859
DECLARE
860
	default_sql text;
861
BEGIN
862
	SELECT adsrc
863
	FROM pg_attribute
864
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
865
	WHERE attrelid = col.table_ AND attname = col.name
866
	INTO STRICT default_sql
867
	;
868
	RETURN default_sql;
869
EXCEPTION
870
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
871
END;
872
$$;
873
874
875
--
876 10134 aaronmk
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
877
--
878
879
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
880
    LANGUAGE sql STABLE
881
    AS $_$
882
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
883
$_$;
884
885
886
--
887
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
888
--
889
890 12235 aaronmk
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
891
ret_type_null: NULL::ret_type
892
';
893 10134 aaronmk
894
895
--
896 8183 aaronmk
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
897 8180 aaronmk
--
898
899
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
900
    LANGUAGE plpgsql STRICT
901
    AS $$
902
BEGIN
903 8183 aaronmk
    PERFORM util.col_type(col);
904 8180 aaronmk
    RETURN true;
905
EXCEPTION
906
    WHEN undefined_column THEN RETURN false;
907
END;
908
$$;
909
910
911
--
912 8183 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
913 8084 aaronmk
--
914
915
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
916 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
917 8084 aaronmk
    AS $$
918
DECLARE
919 8183 aaronmk
    prefix text := util.name(type)||'.';
920 8084 aaronmk
BEGIN
921
    RETURN QUERY
922 8183 aaronmk
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
923
        FROM util.col_names(type) f (name_);
924 8084 aaronmk
END;
925
$$;
926
927
928
--
929 8183 aaronmk
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
930 8151 aaronmk
--
931
932
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
933 12446 aaronmk
    LANGUAGE sql STABLE
934 8151 aaronmk
    AS $_$
935
SELECT attname::text
936
FROM pg_attribute
937 10158 aaronmk
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
938 8151 aaronmk
ORDER BY attnum
939
$_$;
940
941
942
--
943 11667 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
944
--
945
946
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
947
    LANGUAGE plpgsql STABLE STRICT
948
    AS $_$
949
BEGIN
950
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
951
END;
952
$_$;
953
954
955
--
956 8183 aaronmk
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
957 8106 aaronmk
--
958
959
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
960 8169 aaronmk
    LANGUAGE plpgsql STABLE STRICT
961
    AS $$
962
DECLARE
963
    type regtype;
964
BEGIN
965
    SELECT atttypid FROM pg_attribute
966
    WHERE attrelid = col.table_ AND attname = col.name
967
    INTO STRICT type
968
    ;
969
    RETURN type;
970
EXCEPTION
971 8171 aaronmk
    WHEN no_data_found THEN
972 8181 aaronmk
        RAISE undefined_column USING MESSAGE =
973
            concat('undefined column: ', col.name);
974 8169 aaronmk
END;
975
$$;
976 8106 aaronmk
977
978
--
979 12368 aaronmk
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
980
--
981
982
CREATE FUNCTION comment(element oid) RETURNS text
983 12446 aaronmk
    LANGUAGE sql STABLE
984 12368 aaronmk
    AS $_$
985
SELECT description FROM pg_description WHERE objoid = $1
986
$_$;
987
988
989
--
990 11005 aaronmk
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
991
--
992
993
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
994
    LANGUAGE sql IMMUTABLE
995
    AS $_$
996
SELECT util.esc_name__append($2, $1)
997
$_$;
998
999
1000
--
1001 8183 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
1002 8095 aaronmk
--
1003
1004
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
1005 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1006 8095 aaronmk
    AS $_$
1007
SELECT position($1 in $2) > 0 /*1-based offset*/
1008
$_$;
1009
1010
1011
--
1012 12288 aaronmk
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1013
--
1014
1015
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1016
    LANGUAGE sql
1017
    AS $_$
1018
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1019
$_$;
1020
1021
1022
--
1023 12649 aaronmk
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1024
--
1025
1026
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1027
    LANGUAGE sql
1028
    AS $_$
1029
SELECT util.materialize_view($2, $1)
1030
$_$;
1031
1032
1033
--
1034 8183 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
1035 8094 aaronmk
--
1036
1037
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
1038
    LANGUAGE plpgsql STRICT
1039
    AS $$
1040
BEGIN
1041 12595 aaronmk
	PERFORM util.eval(sql);
1042 8094 aaronmk
EXCEPTION
1043 12676 aaronmk
WHEN   duplicate_table
1044
	OR duplicate_object -- eg. constraint
1045
	OR duplicate_column
1046
	OR duplicate_function
1047
THEN NULL;
1048 12595 aaronmk
WHEN invalid_table_definition THEN
1049
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1050
	ELSE RAISE;
1051
	END IF;
1052 8094 aaronmk
END;
1053
$$;
1054
1055
1056
--
1057 8183 aaronmk
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
1058 8094 aaronmk
--
1059
1060 12235 aaronmk
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
1061
idempotent
1062
';
1063 8094 aaronmk
1064
1065
--
1066 12378 aaronmk
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1067
--
1068
1069
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1070 12590 aaronmk
    LANGUAGE sql STABLE
1071 12378 aaronmk
    AS $$
1072
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1073
$$;
1074
1075
1076
--
1077 12668 aaronmk
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1078
--
1079
1080
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1081
    LANGUAGE sql IMMUTABLE
1082
    AS $_$
1083
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1084
$_$;
1085
1086
1087
--
1088 12433 aaronmk
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1089 12430 aaronmk
--
1090
1091 12433 aaronmk
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1092 12430 aaronmk
    LANGUAGE sql IMMUTABLE
1093
    AS $_$
1094 13447 aaronmk
SELECT util.debug_print_value('returns: ', $1, $2);
1095 12430 aaronmk
SELECT $1;
1096
$_$;
1097
1098
1099
--
1100 12250 aaronmk
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1101
--
1102
1103
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1104
    LANGUAGE sql IMMUTABLE
1105
    AS $_$
1106
/* newline before so the query starts at the beginning of the line.
1107
newline after to visually separate queries from one another. */
1108 12534 aaronmk
SELECT util.raise('NOTICE', $$
1109 12474 aaronmk
$$||util.runnable_sql($1)||$$
1110 12464 aaronmk
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1111 12250 aaronmk
$_$;
1112
1113
1114
--
1115 13446 aaronmk
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1116
--
1117
1118
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1119
    LANGUAGE sql IMMUTABLE
1120
    AS $_$
1121
SELECT util.raise('NOTICE', concat($1,
1122 13449 aaronmk
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1123
$$)
1124 13446 aaronmk
$_$;
1125
1126
1127
--
1128 13448 aaronmk
-- Name: debug_print_var(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1129
--
1130
1131
CREATE FUNCTION debug_print_var(var text, value anyelement, encode boolean DEFAULT false) RETURNS void
1132
    LANGUAGE sql IMMUTABLE
1133
    AS $_$
1134
/* can't use EXECUTE in the caller because "No substitution of PL/pgSQL
1135
variables is done on the computed command string"
1136
(http://www.postgresql.org/docs/9.3/static/plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN) */
1137
SELECT util.debug_print_value($1||' = ', $2, $3)
1138
$_$;
1139
1140
1141
--
1142 10364 aaronmk
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1143
--
1144
1145
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1146 12446 aaronmk
    LANGUAGE sql STABLE
1147 10364 aaronmk
    AS $_$
1148
SELECT util.eval2set($$
1149
SELECT col
1150
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1151
LEFT JOIN $$||$2||$$ ON "to" = col
1152
WHERE "from" IS NULL
1153
$$, NULL::text)
1154
$_$;
1155
1156
1157
--
1158
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1159
--
1160
1161 12235 aaronmk
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1162
gets table_''s derived columns (all the columns not in the names table)
1163
';
1164 10364 aaronmk
1165
1166
--
1167 12298 aaronmk
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1168 12044 aaronmk
--
1169
1170 12298 aaronmk
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1171 12427 aaronmk
    LANGUAGE sql
1172 12044 aaronmk
    AS $_$
1173 12653 aaronmk
-- create a diff when the # of copies of a row differs between the tables
1174
SELECT util.to_freq($1);
1175
SELECT util.to_freq($2);
1176 12663 aaronmk
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1177 12653 aaronmk
1178
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1179 12298 aaronmk
$_$;
1180
1181
1182
--
1183
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1184
--
1185
1186
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1187
usage:
1188
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1189 12653 aaronmk
1190
col_type_null (*required*): NULL::shared_base_type
1191 12298 aaronmk
';
1192
1193
1194
--
1195 12491 aaronmk
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1196 12298 aaronmk
--
1197
1198 12491 aaronmk
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
1199 12429 aaronmk
    LANGUAGE plpgsql
1200
    SET search_path TO pg_temp
1201 12298 aaronmk
    AS $_$
1202 12429 aaronmk
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1203
changes of search_path (schema elements are bound at inline time rather than
1204
runtime) */
1205
/* function option search_path is needed to limit the effects of
1206 12492 aaronmk
`SET LOCAL search_path` to the current function */
1207 12429 aaronmk
BEGIN
1208 12491 aaronmk
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1209 12429 aaronmk
1210 12565 aaronmk
	PERFORM util.mk_keys_func(pg_typeof($3));
1211 12429 aaronmk
	RETURN QUERY
1212 12554 aaronmk
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1213 12479 aaronmk
$$/* need to explicitly cast each side to the return type because this does not
1214 12284 aaronmk
happen automatically even when an implicit cast is available */
1215 12479 aaronmk
  left_::$$||util.typeof($3)||$$
1216
, right_::$$||util.typeof($3)
1217 12496 aaronmk
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1218
the *same* base type, *even though* this is optional when using a custom %== */
1219 12553 aaronmk
, util._if($4, $$true/*= CROSS JOIN*/$$,
1220
$$ left_::$$||util.typeof($3)||$$
1221 12496 aaronmk
%== right_::$$||util.typeof($3)||$$
1222
	-- refer to EXPLAIN output for expansion of %==$$
1223 12657 aaronmk
)
1224
,     $$         left_::$$||util.typeof($3)||$$
1225
IS DISTINCT FROM right_::$$||util.typeof($3)
1226
), $3)
1227 12429 aaronmk
	;
1228
END;
1229 12044 aaronmk
$_$;
1230
1231
1232
--
1233 12491 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: -
1234 12280 aaronmk
--
1235
1236 12491 aaronmk
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1237 12280 aaronmk
col_type_null (*required*): NULL::col_type
1238 12299 aaronmk
single_row: whether the tables consist of a single row, which should be
1239
	displayed side-by-side
1240 12282 aaronmk
1241 12498 aaronmk
to match up rows using a subset of the columns, create a custom keys() function
1242
which returns this subset as a record:
1243
-- note that OUT parameters for the returned fields are *not* needed
1244
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1245
  RETURNS record AS
1246
$BODY$
1247
SELECT ($1.key_field_0, $1.key_field_1)
1248
$BODY$
1249
  LANGUAGE sql IMMUTABLE
1250
  COST 100;
1251
1252
1253 12282 aaronmk
to run EXPLAIN on the FULL JOIN query:
1254
# run this function
1255
# look for a NOTICE containing the expanded query that it ran
1256
# run EXPLAIN on this expanded query
1257 12280 aaronmk
';
1258
1259
1260
--
1261 12653 aaronmk
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1262
--
1263
1264
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1265
    LANGUAGE sql
1266
    AS $_$
1267
SELECT * FROM util.diff($1::text, $2::text, $3,
1268
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1269
$_$;
1270
1271
1272
--
1273
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1274
--
1275
1276
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1277
helper function used by diff(regclass, regclass)
1278
1279
usage:
1280
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1281
1282
col_type_null (*required*): NULL::shared_base_type
1283
';
1284
1285
1286
--
1287 8200 aaronmk
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1288
--
1289
1290
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1291 12446 aaronmk
    LANGUAGE sql
1292 8200 aaronmk
    AS $_$
1293
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1294
$_$;
1295
1296
1297
--
1298
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1299
--
1300
1301 12235 aaronmk
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1302
idempotent
1303
';
1304 8200 aaronmk
1305
1306
--
1307 12292 aaronmk
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1308 10362 aaronmk
--
1309
1310 12292 aaronmk
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1311 12446 aaronmk
    LANGUAGE sql
1312 10362 aaronmk
    AS $_$
1313
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1314 12292 aaronmk
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1315 10362 aaronmk
$_$;
1316
1317
1318
--
1319 12292 aaronmk
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1320 10362 aaronmk
--
1321
1322 12292 aaronmk
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1323 12235 aaronmk
idempotent
1324
';
1325 10362 aaronmk
1326
1327
--
1328 12660 aaronmk
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1329
--
1330
1331
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1332
    LANGUAGE sql
1333
    AS $_$
1334 12686 aaronmk
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1335
SELECT NULL::void; -- don't fold away functions called in previous query
1336 12660 aaronmk
$_$;
1337
1338
1339
--
1340
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1341
--
1342
1343
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1344
idempotent
1345
';
1346
1347
1348
--
1349 12587 aaronmk
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1350 12331 aaronmk
--
1351
1352 12587 aaronmk
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1353 12331 aaronmk
    LANGUAGE sql
1354
    AS $_$
1355 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1356
included in the debug SQL */
1357
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1358 12331 aaronmk
$_$;
1359
1360
1361
--
1362 12343 aaronmk
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1363
--
1364
1365 12364 aaronmk
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1366 12343 aaronmk
    LANGUAGE sql
1367
    AS $_$
1368 12347 aaronmk
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1369 12343 aaronmk
||util._if($3, $$ CASCADE$$, ''::text))
1370
$_$;
1371
1372
1373
--
1374 12364 aaronmk
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1375 12343 aaronmk
--
1376
1377 12364 aaronmk
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1378 12343 aaronmk
idempotent
1379
';
1380
1381
1382
--
1383 12413 aaronmk
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1384
--
1385
1386
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1387
    LANGUAGE sql
1388
    AS $_$
1389 12502 aaronmk
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1390 12413 aaronmk
$_$;
1391
1392
1393
--
1394
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1395
--
1396
1397
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1398
    LANGUAGE sql
1399
    AS $_$
1400 12668 aaronmk
SELECT util.debug_print_func_call(util.quote_func_call(
1401
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1402
util.quote_typed($3)))
1403 12667 aaronmk
;
1404 12413 aaronmk
SELECT util.drop_relation(relation, $3)
1405
FROM util.show_relations_like($1, $2) relation
1406
;
1407
SELECT NULL::void; -- don't fold away functions called in previous query
1408
$_$;
1409
1410
1411
--
1412 12292 aaronmk
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1413 10150 aaronmk
--
1414
1415 12292 aaronmk
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1416 12446 aaronmk
    LANGUAGE sql
1417 10150 aaronmk
    AS $_$
1418 12347 aaronmk
SELECT util.drop_relation('TABLE', $1, $2)
1419 10150 aaronmk
$_$;
1420
1421
1422
--
1423 12292 aaronmk
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1424 10150 aaronmk
--
1425
1426 12292 aaronmk
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1427 12235 aaronmk
idempotent
1428
';
1429 10150 aaronmk
1430
1431
--
1432 12292 aaronmk
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1433 12229 aaronmk
--
1434
1435 12292 aaronmk
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1436 12446 aaronmk
    LANGUAGE sql
1437 12229 aaronmk
    AS $_$
1438 12347 aaronmk
SELECT util.drop_relation('VIEW', $1, $2)
1439 12229 aaronmk
$_$;
1440
1441
1442
--
1443 12292 aaronmk
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1444 12229 aaronmk
--
1445
1446 12292 aaronmk
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1447 12235 aaronmk
idempotent
1448
';
1449 12229 aaronmk
1450
1451
--
1452 10322 aaronmk
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1453
--
1454
1455
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1456
    LANGUAGE sql IMMUTABLE
1457
    AS $_$
1458
SELECT util.array_fill($1, 0)
1459
$_$;
1460
1461
1462
--
1463
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1464
--
1465
1466 12235 aaronmk
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1467
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1468
';
1469 10322 aaronmk
1470
1471
--
1472 8183 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1473 8086 aaronmk
--
1474
1475
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1476 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1477 8086 aaronmk
    AS $_$
1478 8183 aaronmk
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1479 8086 aaronmk
$_$;
1480
1481
1482
--
1483 10987 aaronmk
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1484
--
1485
1486
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1487
    LANGUAGE sql IMMUTABLE
1488
    AS $_$
1489
SELECT regexp_replace($2, '("?)$', $1||'\1')
1490
$_$;
1491
1492
1493
--
1494 13455 aaronmk
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1495
--
1496
1497
CREATE FUNCTION eval(queries text[]) RETURNS void
1498
    LANGUAGE sql
1499
    AS $_$
1500
SELECT util.eval(query) FROM unnest($1) query;
1501
SELECT NULL::void; -- don't fold away functions called in previous query
1502
$_$;
1503
1504
1505
--
1506 12531 aaronmk
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1507 9824 aaronmk
--
1508
1509 12531 aaronmk
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1510 12558 aaronmk
    LANGUAGE plpgsql
1511 9824 aaronmk
    AS $$
1512
BEGIN
1513 12531 aaronmk
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1514 12251 aaronmk
	EXECUTE sql;
1515 9824 aaronmk
END;
1516
$$;
1517
1518
1519
--
1520 12181 aaronmk
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1521
--
1522
1523
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1524
    LANGUAGE plpgsql
1525
    AS $$
1526
BEGIN
1527 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1528 12181 aaronmk
	RETURN QUERY EXECUTE sql;
1529
END;
1530
$$;
1531
1532
1533
--
1534
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1535
--
1536
1537 12235 aaronmk
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1538
col_type_null (*required*): NULL::col_type
1539
';
1540 12181 aaronmk
1541
1542
--
1543 12301 aaronmk
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1544
--
1545
1546
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1547
    LANGUAGE plpgsql
1548
    AS $$
1549
BEGIN
1550
	PERFORM util.debug_print_sql(sql);
1551
	RETURN QUERY EXECUTE sql;
1552
END;
1553
$$;
1554
1555
1556
--
1557 12458 aaronmk
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1558 10363 aaronmk
--
1559
1560 12458 aaronmk
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1561 10363 aaronmk
    LANGUAGE plpgsql
1562
    AS $$
1563
BEGIN
1564 12458 aaronmk
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1565 10363 aaronmk
	RETURN QUERY EXECUTE sql;
1566
END;
1567
$$;
1568
1569
1570
--
1571 10129 aaronmk
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1572 10128 aaronmk
--
1573
1574 10129 aaronmk
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1575 12514 aaronmk
    LANGUAGE plpgsql STABLE
1576 10128 aaronmk
    AS $$
1577
DECLARE
1578
	ret_val ret_type_null%TYPE;
1579
BEGIN
1580 12251 aaronmk
	PERFORM util.debug_print_sql(sql);
1581 10128 aaronmk
	EXECUTE sql INTO STRICT ret_val;
1582
	RETURN ret_val;
1583
END;
1584
$$;
1585
1586
1587
--
1588 10129 aaronmk
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1589 10128 aaronmk
--
1590
1591 12235 aaronmk
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1592
ret_type_null: NULL::ret_type
1593
';
1594 10128 aaronmk
1595
1596
--
1597 10131 aaronmk
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1598
--
1599
1600
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1601
    LANGUAGE sql
1602
    AS $_$
1603 10132 aaronmk
SELECT util.eval2val($$SELECT $$||$1, $2)
1604 10131 aaronmk
$_$;
1605
1606
1607
--
1608
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1609
--
1610
1611 12235 aaronmk
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1612
ret_type_null: NULL::ret_type
1613
';
1614 10131 aaronmk
1615
1616
--
1617 10133 aaronmk
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1618
--
1619
1620
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1621
    LANGUAGE sql
1622
    AS $_$
1623
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1624
$_$;
1625
1626
1627
--
1628
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1629
--
1630
1631 12235 aaronmk
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1632
sql: can be NULL, which will be passed through
1633
ret_type_null: NULL::ret_type
1634
';
1635 10133 aaronmk
1636
1637
--
1638 8183 aaronmk
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1639 8182 aaronmk
--
1640
1641
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1642 12446 aaronmk
    LANGUAGE sql STABLE
1643 8182 aaronmk
    AS $_$
1644
SELECT col_name
1645
FROM unnest($2) s (col_name)
1646 8183 aaronmk
WHERE util.col_exists(($1, col_name))
1647 8182 aaronmk
$_$;
1648
1649
1650
--
1651 11830 aaronmk
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1652
--
1653
1654
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1655
    LANGUAGE sql
1656
    AS $_$
1657 12459 aaronmk
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1658 11830 aaronmk
$_$;
1659
1660
1661
--
1662 11833 aaronmk
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1663
--
1664
1665
CREATE FUNCTION explain2notice(sql text) RETURNS void
1666 12449 aaronmk
    LANGUAGE sql
1667
    AS $_$
1668 12534 aaronmk
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1669 12449 aaronmk
$_$;
1670 12448 aaronmk
1671
1672
--
1673
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1674
--
1675
1676
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1677
    LANGUAGE sql
1678
    AS $_$
1679 12464 aaronmk
-- newline before and after to visually separate it from other debug info
1680 12756 aaronmk
SELECT COALESCE($$
1681 12464 aaronmk
EXPLAIN:
1682 12756 aaronmk
$$||util.fold_explain_msg(util.explain2str($1))||$$
1683
$$, '')
1684 11833 aaronmk
$_$;
1685
1686
1687
--
1688 12452 aaronmk
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1689
--
1690
1691
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1692 13403 aaronmk
    LANGUAGE plpgsql
1693
    AS $$
1694
BEGIN
1695
	RETURN util.explain2notice_msg(sql);
1696
EXCEPTION
1697
WHEN syntax_error THEN RETURN NULL; -- non-explainable query
1698
	/* don't use util.is_explainable() because the list provided by Postgres
1699
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1700
	excludes some query types that are in fact EXPLAIN-able */
1701
END;
1702
$$;
1703 12452 aaronmk
1704
1705
--
1706 11832 aaronmk
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1707
--
1708
1709
CREATE FUNCTION explain2str(sql text) RETURNS text
1710
    LANGUAGE sql
1711
    AS $_$
1712
SELECT util.join_strs(explain, $$
1713
$$) FROM util.explain($1)
1714
$_$;
1715
1716
1717 11835 aaronmk
SET default_tablespace = '';
1718
1719
SET default_with_oids = false;
1720
1721 11832 aaronmk
--
1722 11835 aaronmk
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace:
1723 11831 aaronmk
--
1724
1725 11835 aaronmk
CREATE TABLE explain (
1726
    line text NOT NULL
1727
);
1728
1729
1730
--
1731
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1732
--
1733
1734
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1735 11831 aaronmk
    LANGUAGE sql
1736
    AS $_$
1737 11835 aaronmk
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1738
$$||quote_nullable($1)||$$
1739 11831 aaronmk
)$$)
1740
$_$;
1741
1742
1743
--
1744 11836 aaronmk
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1745
--
1746
1747 12235 aaronmk
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1748
usage:
1749 11836 aaronmk
PERFORM util.explain2table($$
1750
query
1751 12235 aaronmk
$$);
1752
';
1753 11836 aaronmk
1754
1755
--
1756 12450 aaronmk
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1757
--
1758
1759
CREATE FUNCTION first_word(str text) RETURNS text
1760
    LANGUAGE sql IMMUTABLE
1761
    AS $_$
1762 12461 aaronmk
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1763 12450 aaronmk
$_$;
1764
1765
1766
--
1767 10323 aaronmk
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1768
--
1769
1770
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1771 10355 aaronmk
    LANGUAGE sql IMMUTABLE
1772 10323 aaronmk
    AS $_$
1773 10355 aaronmk
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1774
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1775
) END
1776 10323 aaronmk
$_$;
1777
1778
1779
--
1780
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1781
--
1782
1783 12235 aaronmk
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1784
ensures that an array will always have proper non-NULL dimensions
1785
';
1786 10323 aaronmk
1787
1788
--
1789 12755 aaronmk
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
1790
--
1791
1792
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1793
    LANGUAGE sql IMMUTABLE
1794
    AS $_$
1795
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1796
$_$;
1797
1798
1799
--
1800 11695 aaronmk
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1801
--
1802
1803
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1804
    LANGUAGE plpgsql
1805
    AS $_$
1806
DECLARE
1807
	PG_EXCEPTION_DETAIL text;
1808 13456 aaronmk
	recreate_users_cmds text[] = util.save_drop_views(users);
1809 11695 aaronmk
BEGIN
1810
	PERFORM util.eval(cmd);
1811 13471 aaronmk
	PERFORM util.create_if_not_exists(recreate_cmd)
1812
	FROM unnest(recreate_users_cmds) recreate_cmd;
1813
		/* create_if_not_exists() rather than eval(), because cmd might manually
1814
		re-create a deleted dependent view, causing it to already exist */
1815 11695 aaronmk
EXCEPTION
1816
WHEN dependent_objects_still_exist THEN
1817
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1818
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1819 13454 aaronmk
	users = util.array_reverse(array(SELECT * FROM util.regexp_matches_group(
1820
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$')));
1821 13450 aaronmk
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
1822
	PERFORM util.debug_print_var('users', users);
1823 11695 aaronmk
	IF util.is_empty(users) THEN RAISE; END IF;
1824
	PERFORM util.force_recreate(cmd, users);
1825
END;
1826
$_$;
1827
1828
1829
--
1830
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1831
--
1832
1833 12235 aaronmk
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1834
idempotent
1835 11695 aaronmk
1836 12235 aaronmk
users: not necessary to provide this because it will be autopopulated
1837
';
1838 11695 aaronmk
1839
1840
--
1841 8321 aaronmk
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1842
--
1843
1844
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1845
    LANGUAGE plpgsql STRICT
1846
    AS $_$
1847
DECLARE
1848
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1849
$$||query;
1850
BEGIN
1851
	EXECUTE mk_view;
1852
EXCEPTION
1853
WHEN invalid_table_definition THEN
1854 8323 aaronmk
	IF SQLERRM = 'cannot drop columns from view'
1855
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1856
	THEN
1857 8321 aaronmk
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1858
		EXECUTE mk_view;
1859
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1860
	END IF;
1861
END;
1862
$_$;
1863
1864
1865
--
1866
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1867
--
1868
1869 12235 aaronmk
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1870
idempotent
1871
';
1872 8321 aaronmk
1873
1874
--
1875 12654 aaronmk
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1876
--
1877
1878
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1879
    LANGUAGE sql STABLE
1880
    AS $_$
1881
SELECT util.eval2val(
1882
$$SELECT NOT EXISTS( -- there is no row that is != 1
1883
	SELECT NULL
1884
	FROM $$||$1||$$
1885
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1886
	LIMIT 1
1887
)
1888
$$, NULL::boolean)
1889
$_$;
1890
1891
1892
--
1893 12661 aaronmk
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1894
--
1895
1896
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1897
    LANGUAGE sql STABLE
1898
    AS $_$
1899
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1900
$_$;
1901
1902
1903
--
1904 11655 aaronmk
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1905
--
1906
1907
CREATE FUNCTION grants_users() RETURNS SETOF text
1908
    LANGUAGE sql IMMUTABLE
1909
    AS $$
1910
VALUES ('bien_read'), ('public_')
1911
$$;
1912
1913
1914
--
1915 8183 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1916 8085 aaronmk
--
1917
1918
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1919 10388 aaronmk
    LANGUAGE sql IMMUTABLE
1920 8085 aaronmk
    AS $_$
1921
SELECT substring($2 for length($1)) = $1
1922
$_$;
1923
1924
1925
--
1926 12296 aaronmk
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1927
--
1928
1929
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1930
    LANGUAGE sql STABLE
1931
    AS $_$
1932
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1933
$_$;
1934
1935
1936
--
1937 10307 aaronmk
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1938
--
1939
1940
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1941
    LANGUAGE sql IMMUTABLE
1942
    AS $_$
1943 10324 aaronmk
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1944 10307 aaronmk
$_$;
1945
1946
1947
--
1948
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1949
--
1950
1951 12235 aaronmk
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1952
avoids repeating the same value for each key
1953
';
1954 10307 aaronmk
1955
1956
--
1957 12218 aaronmk
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1958
--
1959
1960
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1961
    LANGUAGE sql IMMUTABLE
1962
    AS $_$
1963 12222 aaronmk
SELECT COALESCE($1, $2)
1964 12218 aaronmk
$_$;
1965
1966
1967
--
1968
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1969
--
1970
1971 12235 aaronmk
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1972
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1973
';
1974 12218 aaronmk
1975
1976
--
1977 13452 aaronmk
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
1978
--
1979
1980
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
1981
    LANGUAGE sql IMMUTABLE
1982
    AS $_$
1983
SELECT * FROM unnest($1) ORDER BY row_number() OVER () DESC
1984
$_$;
1985
1986
1987
--
1988 12285 aaronmk
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1989
--
1990
1991
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1992
    LANGUAGE sql
1993
    AS $_$
1994
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1995
$_$;
1996
1997
1998
--
1999 13136 aaronmk
-- Name: is_castable(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2000
--
2001
2002
CREATE FUNCTION is_castable(value text, ret_type_null anyelement) RETURNS boolean
2003
    LANGUAGE plpgsql IMMUTABLE
2004
    AS $$
2005
BEGIN
2006
	PERFORM util.cast(value, ret_type_null);
2007 13139 aaronmk
	-- must happen *after* cast check, because NULL is not valid for some types
2008
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
2009 13136 aaronmk
	RETURN true;
2010
EXCEPTION
2011
WHEN data_exception THEN RETURN false;
2012
END;
2013
$$;
2014
2015
2016
--
2017
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
2018
--
2019
2020
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
2021 13139 aaronmk
passes NULL through. however, if NULL is not valid for the type, false will be
2022
returned instead.
2023
2024 13136 aaronmk
ret_type_null: NULL::ret_type
2025
';
2026
2027
2028
--
2029 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
2030
--
2031
2032
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
2033 12446 aaronmk
    LANGUAGE sql STABLE
2034 10137 aaronmk
    AS $_$
2035 12789 aaronmk
SELECT COALESCE(util.col_comment($1) LIKE '
2036
constant
2037
%', false)
2038 10137 aaronmk
$_$;
2039
2040
2041
--
2042 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2043
--
2044
2045
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
2046
    LANGUAGE sql IMMUTABLE
2047
    AS $_$
2048
SELECT util.array_length($1) = 0
2049
$_$;
2050
2051
2052
--
2053 12457 aaronmk
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
2054
--
2055
2056
CREATE FUNCTION is_explain(sql text) RETURNS boolean
2057
    LANGUAGE sql IMMUTABLE
2058
    AS $_$
2059
SELECT upper(util.first_word($1)) = 'EXPLAIN'
2060
$_$;
2061
2062
2063
--
2064 12451 aaronmk
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
2065
--
2066
2067
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
2068
    LANGUAGE sql IMMUTABLE
2069
    AS $_$
2070
SELECT upper(util.first_word($1)) = ANY(
2071
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
2072
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
2073
)
2074
$_$;
2075
2076
2077
--
2078 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2079
--
2080
2081
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
2082
    LANGUAGE sql IMMUTABLE
2083
    AS $_$
2084
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2085
$_$;
2086
2087
2088
--
2089 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2090
--
2091
2092
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2093
    LANGUAGE sql IMMUTABLE
2094
    AS $_$
2095
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2096
$_$;
2097
2098
2099
--
2100 12480 aaronmk
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
2101
--
2102
2103
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2104
    LANGUAGE sql IMMUTABLE
2105
    AS $_$
2106
SELECT upper(util.first_word($1)) = 'SET'
2107
$_$;
2108
2109
2110
--
2111 12330 aaronmk
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
2112
--
2113
2114
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2115 12332 aaronmk
    LANGUAGE sql STABLE
2116 12330 aaronmk
    AS $_$
2117
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2118
$_$;
2119
2120
2121
--
2122 12329 aaronmk
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2123
--
2124
2125
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2126 12332 aaronmk
    LANGUAGE sql STABLE
2127 12329 aaronmk
    AS $_$
2128
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2129
$_$;
2130
2131
2132
--
2133 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2134 4009 aaronmk
--
2135
2136 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2137 12444 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
2138 4009 aaronmk
    AS $_$
2139 4054 aaronmk
SELECT $1 || $3 || $2
2140 2595 aaronmk
$_$;
2141
2142
2143
--
2144 12444 aaronmk
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2145
--
2146
2147
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2148
must be declared STRICT to use the special handling of STRICT aggregating functions
2149
';
2150
2151
2152
--
2153 12436 aaronmk
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2154
--
2155
2156
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2157
    LANGUAGE sql IMMUTABLE
2158
    AS $_$
2159
SELECT $1 -- compare on the entire value
2160
$_$;
2161
2162
2163
--
2164 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2165 10985 aaronmk
--
2166
2167 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2168 10985 aaronmk
    LANGUAGE sql IMMUTABLE
2169
    AS $_$
2170 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2171 10985 aaronmk
$_$;
2172
2173
2174
--
2175 13384 aaronmk
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2176
--
2177
2178
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2179
    LANGUAGE plpgsql
2180
    AS $$
2181
DECLARE
2182
	errors_ct integer = 0;
2183
	loop_var loop_type_null%TYPE;
2184
BEGIN
2185
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2186
	LOOP
2187
		BEGIN
2188
			EXECUTE loop_body_sql USING loop_var;
2189
		EXCEPTION
2190
		WHEN OTHERS THEN
2191
			errors_ct = errors_ct+1;
2192
			PERFORM util.raise_error_warning(SQLERRM);
2193
		END;
2194
	END LOOP;
2195
	IF errors_ct > 0 THEN
2196
		-- can't raise exception because this would roll back the transaction
2197
		PERFORM util.raise_error_warning('there were '||errors_ct
2198
			||' errors: see the WARNINGs for details');
2199
	END IF;
2200
END;
2201
$$;
2202
2203
2204
--
2205 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2206
--
2207
2208
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2209
    LANGUAGE sql IMMUTABLE
2210
    AS $_$
2211
SELECT ltrim($1, $$
2212
$$)
2213
$_$;
2214
2215
2216
--
2217 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2218
--
2219
2220
CREATE FUNCTION map_filter_insert() RETURNS trigger
2221
    LANGUAGE plpgsql
2222
    AS $$
2223
BEGIN
2224
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2225
	RETURN new;
2226
END;
2227
$$;
2228
2229
2230
--
2231 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2232 8146 aaronmk
--
2233
2234
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2235
    LANGUAGE plpgsql STABLE STRICT
2236
    AS $_$
2237
DECLARE
2238
    value text;
2239
BEGIN
2240
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2241 8149 aaronmk
        INTO value USING key;
2242 8146 aaronmk
    RETURN value;
2243
END;
2244
$_$;
2245
2246
2247
--
2248 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2249 10325 aaronmk
--
2250
2251 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2252 10353 aaronmk
    LANGUAGE sql IMMUTABLE
2253 10325 aaronmk
    AS $_$
2254 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
2255 10325 aaronmk
$_$;
2256
2257
2258
--
2259 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2260
--
2261
2262 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
2263
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
2264 10359 aaronmk
2265
[1] inlining of function calls, which is different from constant folding
2266
[2] _map()''s profiling query
2267
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2268
and map_nulls()''s profiling query
2269
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2270 10375 aaronmk
both take ~920 ms.
2271 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.
2272
';
2273 10359 aaronmk
2274
2275
--
2276 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2277 8150 aaronmk
--
2278
2279
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2280
    LANGUAGE plpgsql STABLE STRICT
2281
    AS $_$
2282
BEGIN
2283
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2284
END;
2285
$_$;
2286
2287
2288
--
2289 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2290
--
2291
2292 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2293 12228 aaronmk
    LANGUAGE sql
2294
    AS $_$
2295 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2296 12321 aaronmk
$$||util.ltrim_nl($2));
2297
-- make sure the created table has the correct estimated row count
2298
SELECT util.analyze_($1);
2299 12470 aaronmk
2300
SELECT util.append_comment($1, '
2301
contents generated from:
2302 13397 aaronmk
'||util.ltrim_nl(util.runnable_sql($2))||';
2303 12470 aaronmk
');
2304 12228 aaronmk
$_$;
2305
2306
2307
--
2308 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2309 12228 aaronmk
--
2310
2311 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2312 12235 aaronmk
idempotent
2313
';
2314 12228 aaronmk
2315
2316
--
2317 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2318
--
2319
2320 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2321 12234 aaronmk
    LANGUAGE sql
2322
    AS $_$
2323
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2324
$_$;
2325
2326
2327
--
2328 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2329 12234 aaronmk
--
2330
2331 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2332 12235 aaronmk
idempotent
2333
';
2334 12234 aaronmk
2335
2336
--
2337 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2338
--
2339
2340
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2341 12446 aaronmk
    LANGUAGE sql
2342 8190 aaronmk
    AS $_$
2343 10135 aaronmk
SELECT util.create_if_not_exists($$
2344
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2345 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2346 10135 aaronmk
||quote_literal($2)||$$;
2347 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2348
constant
2349
';
2350 10135 aaronmk
$$)
2351 8190 aaronmk
$_$;
2352
2353
2354
--
2355
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2356
--
2357
2358 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2359
idempotent
2360
';
2361 8190 aaronmk
2362
2363
--
2364 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2365 8187 aaronmk
--
2366
2367 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2368 8187 aaronmk
    LANGUAGE plpgsql STRICT
2369
    AS $_$
2370
DECLARE
2371
    type regtype = util.typeof(expr, col.table_::text::regtype);
2372
    col_name_sql text = quote_ident(col.name);
2373
BEGIN
2374 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2375
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2376 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2377
$$||expr||$$;
2378
$$);
2379
END;
2380
$_$;
2381
2382
2383
--
2384 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2385 8188 aaronmk
--
2386
2387 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2388
idempotent
2389
';
2390 8188 aaronmk
2391
2392
--
2393 12554 aaronmk
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2394 12475 aaronmk
--
2395
2396 12554 aaronmk
CREATE FUNCTION mk_diff_query(left_ text, right_ text, cols text DEFAULT 'left_, right_'::text, join_cond text DEFAULT 'left_ %== right_ -- refer to EXPLAIN output for expansion of %=='::text, filter text DEFAULT 'left_ IS DISTINCT FROM right_'::text) RETURNS text
2397 12475 aaronmk
    LANGUAGE sql IMMUTABLE
2398
    AS $_$
2399
SELECT
2400 12478 aaronmk
$$SELECT
2401 12554 aaronmk
$$||$3||$$
2402 12555 aaronmk
FROM      $$||$1||$$ left_
2403 12554 aaronmk
FULL JOIN $$||$2||$$ right_
2404
ON $$||$4||$$
2405
WHERE $$||$5||$$
2406 12475 aaronmk
ORDER BY left_, right_
2407
$$
2408
$_$;
2409
2410
2411
--
2412 12564 aaronmk
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2413
--
2414
2415
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2416 12591 aaronmk
    LANGUAGE sql
2417 12564 aaronmk
    AS $_$
2418 12570 aaronmk
-- keys()
2419 12564 aaronmk
SELECT util.mk_keys_func($1, ARRAY(
2420
SELECT col FROM util.typed_cols($1) col
2421
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2422 12570 aaronmk
));
2423
2424 12571 aaronmk
-- values_()
2425 12570 aaronmk
SELECT util.mk_keys_func($1, COALESCE(
2426
	NULLIF(ARRAY(
2427
	SELECT col FROM util.typed_cols($1) col
2428
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2429
	), ARRAY[]::util.col_cast[])
2430
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2431 12571 aaronmk
, 'values_');
2432 12564 aaronmk
$_$;
2433
2434
2435
--
2436 12569 aaronmk
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2437 12561 aaronmk
--
2438
2439 12569 aaronmk
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2440 12591 aaronmk
    LANGUAGE sql
2441 12561 aaronmk
    AS $_$
2442 12567 aaronmk
SELECT util.create_if_not_exists($$
2443 12577 aaronmk
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2444
($$||util.mk_typed_cols_list($2)||$$);
2445 12671 aaronmk
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2446
autogenerated
2447
';
2448 12594 aaronmk
$$);
2449 12577 aaronmk
2450 12594 aaronmk
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2451
$_$;
2452
2453
2454
--
2455
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2456
--
2457
2458
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2459
    LANGUAGE sql
2460
    AS $_$
2461
SELECT util.create_if_not_exists($$
2462 12581 aaronmk
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2463 12577 aaronmk
||util.qual_name($1)||$$)
2464 12594 aaronmk
  RETURNS $$||util.qual_name($2)||$$ AS
2465 12561 aaronmk
$BODY1$
2466 12577 aaronmk
SELECT ROW($$||
2467 12594 aaronmk
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2468
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2469 12561 aaronmk
$BODY1$
2470
  LANGUAGE sql IMMUTABLE
2471
  COST 100;
2472 12594 aaronmk
$$);
2473 12561 aaronmk
$_$;
2474
2475
2476
--
2477 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2478 8139 aaronmk
--
2479
2480
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2481 12446 aaronmk
    LANGUAGE sql
2482 8139 aaronmk
    AS $_$
2483 8183 aaronmk
SELECT util.create_if_not_exists($$
2484 8141 aaronmk
CREATE TABLE $$||$1||$$
2485 8139 aaronmk
(
2486 8183 aaronmk
    LIKE util.map INCLUDING ALL
2487 10110 aaronmk
);
2488
2489
CREATE TRIGGER map_filter_insert
2490
  BEFORE INSERT
2491
  ON $$||$1||$$
2492
  FOR EACH ROW
2493
  EXECUTE PROCEDURE util.map_filter_insert();
2494 8141 aaronmk
$$)
2495 8139 aaronmk
$_$;
2496
2497
2498
--
2499 12725 aaronmk
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2500
--
2501
2502
CREATE FUNCTION mk_not_null(text) RETURNS text
2503
    LANGUAGE sql IMMUTABLE
2504
    AS $_$
2505
SELECT COALESCE($1, '<NULL>')
2506
$_$;
2507
2508
2509
--
2510 12556 aaronmk
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2511
--
2512
2513
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2514
    LANGUAGE sql IMMUTABLE
2515
    AS $_$
2516 12559 aaronmk
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2517
util.qual_name((unnest).type), ''), '')
2518 12556 aaronmk
FROM unnest($1)
2519
$_$;
2520
2521
2522
--
2523 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2524
--
2525
2526
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2527
    LANGUAGE sql IMMUTABLE
2528
    AS $_$
2529 12486 aaronmk
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2530 12236 aaronmk
$_$;
2531
2532
2533
--
2534 12486 aaronmk
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2535
--
2536
2537
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2538
auto-appends util to the search_path to enable use of util operators
2539
';
2540
2541
2542
--
2543 13474 aaronmk
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2544
--
2545
2546
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2547
    LANGUAGE sql STABLE
2548
    AS $_$
2549 13479 aaronmk
SELECT COALESCE($$COMMENT ON TABLE $$||$1||$$ IS $$
2550 13481 aaronmk
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2551 13474 aaronmk
$_$;
2552
2553
2554
--
2555 12467 aaronmk
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2556
--
2557
2558
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2559
    LANGUAGE sql IMMUTABLE
2560
    AS $_$
2561
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2562
$_$;
2563
2564
2565
--
2566 12466 aaronmk
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2567 12270 aaronmk
--
2568
2569 12466 aaronmk
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2570 12270 aaronmk
    LANGUAGE sql IMMUTABLE
2571
    AS $_$
2572 12432 aaronmk
/* debug_print_return_value() needed because this function is used with EXECUTE
2573
rather than util.eval() (in order to affect the calling function), so the
2574
search_path would not otherwise be printed */
2575 12487 aaronmk
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2576
||$$ search_path TO $$||$1
2577 12270 aaronmk
$_$;
2578
2579
2580
--
2581 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2582
--
2583
2584
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2585 12446 aaronmk
    LANGUAGE sql
2586 10113 aaronmk
    AS $_$
2587 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2588 10113 aaronmk
$_$;
2589
2590
2591
--
2592
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2593
--
2594
2595 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2596
idempotent
2597
';
2598 10113 aaronmk
2599
2600
--
2601 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2602
--
2603
2604
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2605
    LANGUAGE plpgsql STRICT
2606
    AS $_$
2607
DECLARE
2608
	view_qual_name text = util.qual_name(view_);
2609
BEGIN
2610
	EXECUTE $$
2611
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2612
  RETURNS SETOF $$||view_||$$ AS
2613
$BODY1$
2614
SELECT * FROM $$||view_qual_name||$$
2615
ORDER BY sort_col
2616
LIMIT $1 OFFSET $2
2617
$BODY1$
2618
  LANGUAGE sql STABLE
2619
  COST 100
2620
  ROWS 1000
2621
$$;
2622
2623
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2624
END;
2625
$_$;
2626
2627
2628
--
2629 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2630
--
2631
2632
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2633
    LANGUAGE plpgsql STRICT
2634
    AS $_$
2635 10990 aaronmk
DECLARE
2636
	view_qual_name text = util.qual_name(view_);
2637
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2638 8325 aaronmk
BEGIN
2639
	EXECUTE $$
2640 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2641
  RETURNS integer AS
2642
$BODY1$
2643
SELECT $$||quote_ident(row_num_col)||$$
2644
FROM $$||view_qual_name||$$
2645
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2646
LIMIT 1
2647
$BODY1$
2648
  LANGUAGE sql STABLE
2649
  COST 100;
2650
$$;
2651
2652
	EXECUTE $$
2653 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2654
  RETURNS SETOF $$||view_||$$ AS
2655
$BODY1$
2656 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
2657
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2658
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2659
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2660 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
2661 8325 aaronmk
$BODY1$
2662
  LANGUAGE sql STABLE
2663
  COST 100
2664
  ROWS 1000
2665
$$;
2666 11010 aaronmk
2667
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2668
END;
2669
$_$;
2670
2671
2672
--
2673
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2674
--
2675
2676
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2677
    LANGUAGE plpgsql STRICT
2678
    AS $_$
2679
DECLARE
2680
	view_qual_name text = util.qual_name(view_);
2681
BEGIN
2682 8326 aaronmk
	EXECUTE $$
2683
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2684
  RETURNS SETOF $$||view_||$$
2685
  SET enable_sort TO 'off'
2686
  AS
2687
$BODY1$
2688 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
2689 8326 aaronmk
$BODY1$
2690
  LANGUAGE sql STABLE
2691
  COST 100
2692
  ROWS 1000
2693
;
2694
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2695
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2696
If you want to run EXPLAIN and get expanded output, use the regular subset
2697
function instead. (When a config param is set on a function, EXPLAIN produces
2698
just a function scan.)
2699
';
2700
$$;
2701 8325 aaronmk
END;
2702
$_$;
2703
2704
2705
--
2706 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2707
--
2708
2709 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2710
creates subset function which turns off enable_sort
2711
';
2712 11010 aaronmk
2713
2714
--
2715 12576 aaronmk
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2716
--
2717
2718
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2719
    LANGUAGE sql IMMUTABLE
2720
    AS $_$
2721 12579 aaronmk
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2722 12576 aaronmk
util.qual_name((unnest).type), ', '), '')
2723
FROM unnest($1)
2724
$_$;
2725
2726
2727
--
2728 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2729
--
2730
2731
CREATE FUNCTION name(table_ regclass) RETURNS text
2732
    LANGUAGE sql STABLE
2733
    AS $_$
2734
SELECT relname::text FROM pg_class WHERE oid = $1
2735
$_$;
2736
2737
2738
--
2739 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2740 8083 aaronmk
--
2741
2742
CREATE FUNCTION name(type regtype) RETURNS text
2743 12446 aaronmk
    LANGUAGE sql STABLE
2744 8083 aaronmk
    AS $_$
2745
SELECT typname::text FROM pg_type WHERE oid = $1
2746
$_$;
2747
2748
2749
--
2750 12360 aaronmk
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2751 12355 aaronmk
--
2752
2753 12360 aaronmk
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2754 12355 aaronmk
    LANGUAGE sql IMMUTABLE
2755
    AS $_$
2756 12360 aaronmk
SELECT octet_length($1) >= util.namedatalen() - $2
2757 12355 aaronmk
$_$;
2758
2759
2760
--
2761 12354 aaronmk
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2762
--
2763
2764
CREATE FUNCTION namedatalen() RETURNS integer
2765
    LANGUAGE sql IMMUTABLE
2766
    AS $$
2767
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2768
$$;
2769
2770
2771
--
2772 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2773
--
2774
2775
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2776
    LANGUAGE sql IMMUTABLE
2777
    AS $_$
2778 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2779 9958 aaronmk
$_$;
2780
2781
2782
--
2783 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2784
--
2785
2786
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2787 9957 aaronmk
    LANGUAGE sql IMMUTABLE
2788 9956 aaronmk
    AS $_$
2789
SELECT $1 IS NOT NULL
2790
$_$;
2791
2792
2793
--
2794 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2795
--
2796
2797
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2798
    LANGUAGE sql IMMUTABLE
2799
    AS $_$
2800
SELECT util.hstore($1, NULL) || '*=>*'
2801
$_$;
2802
2803
2804
--
2805
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2806
--
2807
2808 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2809
for use with _map()
2810
';
2811 10373 aaronmk
2812
2813
--
2814 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2815 10984 aaronmk
--
2816
2817 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2818 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2819
    AS $_$
2820 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2821 10984 aaronmk
$_$;
2822
2823
2824
--
2825 12659 aaronmk
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2826
--
2827
2828
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2829
    LANGUAGE sql STABLE
2830
    AS $_$
2831
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2832
$_$;
2833
2834
2835
--
2836 12651 aaronmk
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2837
--
2838
2839
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2840
    LANGUAGE sql
2841
    AS $_$
2842
SELECT util.eval($$INSERT INTO $$||$1||$$
2843
$$||util.ltrim_nl($2));
2844
-- make sure the created table has the correct estimated row count
2845
SELECT util.analyze_($1);
2846
$_$;
2847
2848
2849
--
2850 12575 aaronmk
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2851
--
2852
2853
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2854
    LANGUAGE sql IMMUTABLE
2855
    AS $_$
2856
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2857
$_$;
2858
2859
2860
--
2861 12494 aaronmk
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2862
--
2863
2864
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2865
    LANGUAGE sql
2866
    AS $_$
2867
SELECT util.set_comment($1, concat($2, util.comment($1)))
2868
$_$;
2869
2870
2871
--
2872
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2873
--
2874
2875
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2876
comment: must start and end with a newline
2877
';
2878
2879
2880
--
2881 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2882
--
2883
2884
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2885
    LANGUAGE sql IMMUTABLE
2886
    AS $_$
2887
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2888
$_$;
2889
2890
2891
--
2892 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2893
--
2894
2895
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2896 12446 aaronmk
    LANGUAGE sql STABLE
2897 12267 aaronmk
    SET search_path TO pg_temp
2898 10988 aaronmk
    AS $_$
2899 12267 aaronmk
SELECT $1::text
2900 10988 aaronmk
$_$;
2901
2902
2903
--
2904 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2905
--
2906
2907
CREATE FUNCTION qual_name(type regtype) RETURNS text
2908 12446 aaronmk
    LANGUAGE sql STABLE
2909 12267 aaronmk
    SET search_path TO pg_temp
2910
    AS $_$
2911
SELECT $1::text
2912
$_$;
2913
2914
2915
--
2916
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2917
--
2918
2919
COMMENT ON FUNCTION qual_name(type regtype) IS '
2920
a type''s schema-qualified name
2921
';
2922
2923
2924
--
2925 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2926
--
2927
2928
CREATE FUNCTION qual_name(type unknown) RETURNS text
2929 12446 aaronmk
    LANGUAGE sql STABLE
2930 12268 aaronmk
    AS $_$
2931
SELECT util.qual_name($1::text::regtype)
2932
$_$;
2933
2934
2935
--
2936 12376 aaronmk
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2937
--
2938
2939
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2940
    LANGUAGE sql IMMUTABLE
2941
    AS $_$
2942
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2943
$_$;
2944
2945
2946
--
2947
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2948
--
2949
2950
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2951
    LANGUAGE sql IMMUTABLE
2952
    AS $_$
2953
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2954
$_$;
2955
2956
2957
--
2958 12371 aaronmk
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2959
--
2960
2961
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2962
    LANGUAGE sql IMMUTABLE
2963
    AS $_$
2964 12437 aaronmk
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2965 12371 aaronmk
$_$;
2966
2967
2968
--
2969 12530 aaronmk
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2970
--
2971
2972
CREATE FUNCTION raise(type text, msg text) RETURNS void
2973
    LANGUAGE sql IMMUTABLE
2974 12560 aaronmk
    AS $_X$
2975 12530 aaronmk
SELECT util.eval($$
2976
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2977
  RETURNS void AS
2978 12560 aaronmk
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2979
$__BODY1$
2980 12530 aaronmk
BEGIN
2981
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2982
END;
2983 12560 aaronmk
$__BODY1$
2984 12530 aaronmk
  LANGUAGE plpgsql IMMUTABLE
2985
  COST 100;
2986 12532 aaronmk
$$, verbose_ := false);
2987 12530 aaronmk
2988 12532 aaronmk
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2989 12560 aaronmk
$_X$;
2990 12530 aaronmk
2991
2992
--
2993 12533 aaronmk
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2994
--
2995
2996
COMMENT ON FUNCTION raise(type text, msg text) IS '
2997
type: a log level from
2998
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2999
or a condition name from
3000
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
3001
';
3002
3003
3004
--
3005 12536 aaronmk
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
3006 12311 aaronmk
--
3007
3008 12536 aaronmk
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3009 12441 aaronmk
    LANGUAGE sql IMMUTABLE
3010 12311 aaronmk
    AS $_$
3011 12536 aaronmk
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3012 12311 aaronmk
$_$;
3013
3014
3015
--
3016 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3017
--
3018
3019
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3020
    LANGUAGE plpgsql IMMUTABLE STRICT
3021
    AS $$
3022
BEGIN
3023
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3024
END;
3025
$$;
3026
3027
3028
--
3029 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3030
--
3031
3032
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3033
    LANGUAGE sql IMMUTABLE
3034
    AS $_$
3035
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3036
$_$;
3037
3038
3039
--
3040 12333 aaronmk
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3041
--
3042
3043
CREATE FUNCTION regexp_quote(str text) RETURNS text
3044
    LANGUAGE sql IMMUTABLE
3045
    AS $_$
3046
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3047
$_$;
3048
3049
3050
--
3051 12375 aaronmk
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
3052
--
3053
3054
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3055
    LANGUAGE sql IMMUTABLE
3056
    AS $_$
3057
SELECT (CASE WHEN right($1, 1) = ')'
3058 12377 aaronmk
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3059 12375 aaronmk
$_$;
3060
3061
3062
--
3063 12344 aaronmk
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3064
--
3065
3066
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3067
    LANGUAGE sql STABLE
3068
    AS $_$
3069
SELECT util.relation_type(util.relation_type_char($1))
3070
$_$;
3071
3072
3073
--
3074 12340 aaronmk
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3075 12339 aaronmk
--
3076
3077 12340 aaronmk
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3078 12339 aaronmk
    LANGUAGE sql IMMUTABLE
3079
    AS $_$
3080 12593 aaronmk
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3081 12339 aaronmk
$_$;
3082
3083
3084
--
3085 12588 aaronmk
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3086
--
3087
3088
CREATE FUNCTION relation_type(type regtype) RETURNS text
3089
    LANGUAGE sql IMMUTABLE
3090
    AS $$
3091
SELECT 'TYPE'::text
3092
$$;
3093
3094
3095
--
3096 12341 aaronmk
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
3097
--
3098
3099
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3100
    LANGUAGE sql STABLE
3101
    AS $_$
3102
SELECT relkind FROM pg_class WHERE oid = $1
3103
$_$;
3104
3105
3106
--
3107 12293 aaronmk
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
3108
--
3109
3110
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3111
    LANGUAGE sql
3112
    AS $_$
3113
/* can't have in_table/out_table inherit from *each other*, because inheritance
3114
also causes the rows of the parent table to be included in the child table.
3115
instead, they need to inherit from a common, empty table. */
3116 12382 aaronmk
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3117
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3118 13098 aaronmk
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3119 12293 aaronmk
SELECT util.inherit($2, $4);
3120
SELECT util.inherit($3, $4);
3121
3122
SELECT util.rematerialize_query($1, $$
3123
SELECT * FROM util.diff(
3124 12419 aaronmk
  $$||util.quote_typed($2)||$$
3125
, $$||util.quote_typed($3)||$$
3126 12293 aaronmk
, NULL::$$||$4||$$)
3127
$$);
3128 12303 aaronmk
3129
/* the table unfortunately cannot be *materialized* in human-readable form,
3130
because this would create column name collisions between the two sides */
3131 12495 aaronmk
SELECT util.prepend_comment($1, '
3132 12303 aaronmk
to view this table in human-readable form (with each side''s tuple column
3133
expanded to its component fields):
3134 12572 aaronmk
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3135 13092 aaronmk
3136
to display NULL values that are extra or missing:
3137
SELECT * FROM '||$1||';
3138 12303 aaronmk
');
3139 12293 aaronmk
$_$;
3140
3141
3142
--
3143
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3144
--
3145
3146
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3147
type_table (*required*): table to create as the shared base type
3148
';
3149
3150
3151
--
3152 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3153
--
3154
3155
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3156
    LANGUAGE sql
3157
    AS $_$
3158
SELECT util.drop_table($1);
3159
SELECT util.materialize_query($1, $2);
3160
$_$;
3161
3162
3163
--
3164
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3165
--
3166
3167
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3168
idempotent, but repeats action each time
3169
';
3170
3171
3172
--
3173 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3174
--
3175
3176 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3177 12247 aaronmk
    LANGUAGE sql
3178
    AS $_$
3179
SELECT util.drop_table($1);
3180
SELECT util.materialize_view($1, $2);
3181
$_$;
3182
3183
3184
--
3185 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3186 12247 aaronmk
--
3187
3188 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3189 12247 aaronmk
idempotent, but repeats action each time
3190
';
3191
3192
3193
--
3194 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3195 8137 aaronmk
--
3196
3197 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3198 12446 aaronmk
    LANGUAGE sql
3199 8137 aaronmk
    AS $_$
3200 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3201 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3202 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
3203
SELECT NULL::void; -- don't fold away functions called in previous query
3204 8137 aaronmk
$_$;
3205
3206
3207
--
3208 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3209 8137 aaronmk
--
3210
3211 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3212
idempotent
3213
';
3214 8137 aaronmk
3215
3216
--
3217 12349 aaronmk
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3218
--
3219
3220
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3221
    LANGUAGE sql
3222
    AS $_$
3223 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3224
included in the debug SQL */
3225
SELECT util.rename_relation(util.qual_name($1), $2)
3226 12349 aaronmk
$_$;
3227
3228
3229
--
3230
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3231
--
3232
3233 12364 aaronmk
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3234 12349 aaronmk
    LANGUAGE sql
3235
    AS $_$
3236
/* 'ALTER TABLE can be used with views too'
3237
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3238 12363 aaronmk
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3239
||quote_ident($2))
3240 12349 aaronmk
$_$;
3241
3242
3243
--
3244 12364 aaronmk
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3245 12349 aaronmk
--
3246
3247 12364 aaronmk
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3248 12349 aaronmk
idempotent
3249
';
3250
3251
3252
--
3253 12358 aaronmk
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3254 12350 aaronmk
--
3255
3256 12358 aaronmk
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3257 12350 aaronmk
    LANGUAGE sql IMMUTABLE
3258
    AS $_$
3259 12358 aaronmk
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3260 12350 aaronmk
$_$;
3261
3262
3263
--
3264 12358 aaronmk
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3265
--
3266
3267
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3268
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
3269
';
3270
3271
3272
--
3273 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3274
--
3275
3276
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3277 12446 aaronmk
    LANGUAGE sql
3278 10297 aaronmk
    AS $_$
3279 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3280
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3281 10297 aaronmk
SELECT util.set_col_names($1, $2);
3282
$_$;
3283
3284
3285
--
3286
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3287
--
3288
3289 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3290
idempotent.
3291
alters the names table, so it will need to be repopulated after running this function.
3292
';
3293 10297 aaronmk
3294
3295
--
3296 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3297 8143 aaronmk
--
3298
3299
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3300 12446 aaronmk
    LANGUAGE sql
3301 8143 aaronmk
    AS $_$
3302 10152 aaronmk
SELECT util.drop_table($1);
3303 8183 aaronmk
SELECT util.mk_map_table($1);
3304 8143 aaronmk
$_$;
3305
3306
3307
--
3308 13096 aaronmk
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3309
--
3310
3311
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3312
    LANGUAGE sql
3313
    AS $_$
3314
SELECT util.drop_column($1, $2, force := true)
3315
$_$;
3316
3317
3318
--
3319 12356 aaronmk
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3320
--
3321
3322
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3323
    LANGUAGE sql IMMUTABLE
3324
    AS $_$
3325
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3326
$_$;
3327
3328
3329
--
3330 12473 aaronmk
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3331
--
3332
3333
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3334
    LANGUAGE sql IMMUTABLE
3335
    AS $_$
3336 12481 aaronmk
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3337
ELSE util.mk_set_search_path(for_printing := true)||$$;
3338
$$ END)||$1
3339 12473 aaronmk
$_$;
3340
3341
3342
--
3343 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3344
--
3345
3346
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3347
    LANGUAGE plpgsql STRICT
3348 13467 aaronmk
    AS $$
3349 11652 aaronmk
DECLARE
3350
	result text = NULL;
3351
BEGIN
3352
	BEGIN
3353 13470 aaronmk
		result = util.show_create_view(view_, replace := false);
3354
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3355
			(eg. invalid_table_definition), instead of the standard
3356
			duplicate_table exception caught by util.create_if_not_exists() */
3357 13467 aaronmk
		PERFORM util.drop_view(view_);
3358 11652 aaronmk
	EXCEPTION
3359
		WHEN undefined_table THEN NULL;
3360
	END;
3361
	RETURN result;
3362
END;
3363 13467 aaronmk
$$;
3364 11652 aaronmk
3365
3366
--
3367 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3368
--
3369
3370 13456 aaronmk
CREATE FUNCTION save_drop_views(views text[]) RETURNS text[]
3371 11660 aaronmk
    LANGUAGE sql
3372
    AS $_$
3373 13456 aaronmk
SELECT array(SELECT util.save_drop_view(view_) FROM unnest($1) view_)
3374 11660 aaronmk
$_$;
3375
3376
3377
--
3378 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3379
--
3380
3381
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3382
    LANGUAGE sql STABLE
3383
    AS $_$
3384
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3385
$_$;
3386
3387
3388
--
3389 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3390
--
3391
3392
CREATE FUNCTION schema(table_ regclass) RETURNS text
3393
    LANGUAGE sql STABLE
3394
    AS $_$
3395 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3396 12242 aaronmk
$_$;
3397
3398
3399
--
3400 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3401
--
3402
3403
CREATE FUNCTION schema(type regtype) RETURNS text
3404
    LANGUAGE sql STABLE
3405
    AS $_$
3406 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3407 10794 aaronmk
$_$;
3408
3409
3410
--
3411
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3412
--
3413
3414
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3415
    LANGUAGE sql STABLE
3416
    AS $_$
3417
SELECT util.schema(pg_typeof($1))
3418
$_$;
3419
3420
3421
--
3422 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3423
--
3424
3425
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3426
    LANGUAGE sql STABLE
3427
    AS $_$
3428
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3429
$_$;
3430
3431
3432
--
3433 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3434
--
3435
3436 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3437
a schema bundle is a group of schemas with a common prefix
3438
';
3439 12135 aaronmk
3440
3441
--
3442
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3443
--
3444
3445
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3446
    LANGUAGE sql
3447
    AS $_$
3448
SELECT util.schema_rename(old_schema,
3449
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3450
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3451
SELECT NULL::void; -- don't fold away functions called in previous query
3452
$_$;
3453
3454
3455
--
3456
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3457
--
3458
3459
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3460
    LANGUAGE plpgsql
3461
    AS $$
3462
BEGIN
3463
	-- don't schema_bundle_rm() the schema_bundle to keep!
3464
	IF replace = with_ THEN RETURN; END IF;
3465
3466
	PERFORM util.schema_bundle_rm(replace);
3467
	PERFORM util.schema_bundle_rename(with_, replace);
3468
END;
3469
$$;
3470
3471
3472
--
3473
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3474
--
3475
3476
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3477
    LANGUAGE sql
3478
    AS $_$
3479
SELECT util.schema_rm(schema)
3480
FROM util.schema_bundle_get_schemas($1) f (schema);
3481
SELECT NULL::void; -- don't fold away functions called in previous query
3482
$_$;
3483
3484
3485
--
3486 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3487 10795 aaronmk
--
3488
3489 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3490 10795 aaronmk
    LANGUAGE sql STABLE
3491
    AS $_$
3492
SELECT quote_ident(util.schema($1))
3493
$_$;
3494
3495
3496
--
3497 12324 aaronmk
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3498
--
3499
3500
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3501 12334 aaronmk
    LANGUAGE sql IMMUTABLE
3502 12324 aaronmk
    AS $_$
3503
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3504
$_$;
3505
3506
3507
--
3508 12304 aaronmk
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3509
--
3510
3511
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3512
    LANGUAGE sql STABLE
3513
    AS $_$
3514
SELECT oid FROM pg_namespace WHERE nspname = $1
3515
$_$;
3516
3517
3518
--
3519 12504 aaronmk
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3520
--
3521
3522
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3523
    LANGUAGE sql IMMUTABLE
3524
    AS $_$
3525
SELECT util.schema_regexp(schema_anchor := $1)
3526
$_$;
3527
3528
3529
--
3530 12501 aaronmk
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3531
--
3532
3533
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3534
    LANGUAGE sql IMMUTABLE
3535
    AS $_$
3536
SELECT util.str_equality_regexp(util.schema($1))
3537
$_$;
3538
3539
3540
--
3541 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3542
--
3543
3544
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3545
    LANGUAGE sql
3546
    AS $_$
3547
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3548
$_$;
3549
3550
3551
--
3552 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3553
--
3554
3555
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3556
    LANGUAGE plpgsql
3557
    AS $$
3558
BEGIN
3559
	-- don't schema_rm() the schema to keep!
3560
	IF replace = with_ THEN RETURN; END IF;
3561
3562
	PERFORM util.schema_rm(replace);
3563
	PERFORM util.schema_rename(with_, replace);
3564
END;
3565
$$;
3566
3567
3568
--
3569 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3570
--
3571
3572
CREATE FUNCTION schema_rm(schema text) RETURNS void
3573
    LANGUAGE sql
3574
    AS $_$
3575
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3576
$_$;
3577
3578
3579
--
3580 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3581
--
3582
3583
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3584 12446 aaronmk
    LANGUAGE sql
3585 9825 aaronmk
    AS $_$
3586
SELECT util.eval(
3587
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3588
$_$;
3589
3590
3591
--
3592 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3593 8153 aaronmk
--
3594
3595
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3596
    LANGUAGE plpgsql STRICT
3597
    AS $_$
3598
DECLARE
3599 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
3600
    new text[] = ARRAY(SELECT util.map_values(names));
3601 8153 aaronmk
BEGIN
3602
    old = old[1:array_length(new, 1)]; -- truncate to same length
3603 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3604
||$$ TO $$||quote_ident(value))
3605 10149 aaronmk
    FROM each(hstore(old, new))
3606
    WHERE value != key -- not same name
3607
    ;
3608 8153 aaronmk
END;
3609
$_$;
3610
3611
3612
--
3613 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3614 8153 aaronmk
--
3615
3616 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3617
idempotent
3618
';
3619 8153 aaronmk
3620
3621
--
3622 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3623
--
3624
3625
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3626
    LANGUAGE plpgsql STRICT
3627
    AS $_$
3628
DECLARE
3629
	row_ util.map;
3630
BEGIN
3631 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
3632
	BEGIN
3633
		PERFORM util.set_col_names(table_, names);
3634
	EXCEPTION
3635
		WHEN array_subscript_error THEN -- selective suppress
3636
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3637
				-- metadata cols not yet added
3638 12568 aaronmk
			ELSE RAISE;
3639 10715 aaronmk
			END IF;
3640
	END;
3641
3642 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3643 10145 aaronmk
	LOOP
3644 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
3645
			substring(row_."from" from 2));
3646 10145 aaronmk
	END LOOP;
3647
3648
	PERFORM util.set_col_names(table_, names);
3649
END;
3650
$_$;
3651
3652
3653
--
3654
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3655
--
3656
3657 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3658
idempotent.
3659
the metadata mappings must be *last* in the names table.
3660
';
3661 10145 aaronmk
3662
3663
--
3664 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3665 8107 aaronmk
--
3666
3667
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3668 12733 aaronmk
    LANGUAGE sql
3669 8107 aaronmk
    AS $_$
3670 12734 aaronmk
SELECT util.eval(COALESCE(
3671
$$ALTER TABLE $$||$1||$$
3672 12732 aaronmk
$$||(
3673
	SELECT
3674
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3675
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
3676
, $$)
3677
	FROM
3678
	(
3679
		SELECT
3680
		  quote_ident(col_name) AS col_name_sql
3681 12733 aaronmk
		, util.col_type(($1, col_name)) AS curr_type
3682 12732 aaronmk
		, type AS target_type
3683 12733 aaronmk
		FROM unnest($2)
3684 12732 aaronmk
	) s
3685
	WHERE curr_type != target_type
3686 12734 aaronmk
), ''))
3687 8107 aaronmk
$_$;
3688
3689
3690
--
3691 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3692 8107 aaronmk
--
3693
3694 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3695
idempotent
3696
';
3697 8107 aaronmk
3698
3699
--
3700 12302 aaronmk
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3701
--
3702
3703
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3704 12446 aaronmk
    LANGUAGE sql
3705 12302 aaronmk
    AS $_$
3706 13477 aaronmk
SELECT util.eval(util.mk_set_comment($1, $2))
3707 12302 aaronmk
$_$;
3708
3709
3710
--
3711 12482 aaronmk
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3712
--
3713
3714
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3715
    LANGUAGE sql
3716
    AS $_$
3717
SELECT util.eval(util.mk_set_search_path($1, $2))
3718
$_$;
3719
3720
3721
--
3722 13468 aaronmk
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3723 11651 aaronmk
--
3724
3725 13468 aaronmk
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
3726 11651 aaronmk
    LANGUAGE sql STABLE
3727
    AS $_$
3728 13468 aaronmk
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
3729
||$1||$$ AS
3730 13482 aaronmk
$$||pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
3731 11656 aaronmk
$$||util.show_grants_for($1)
3732 13482 aaronmk
||util.show_set_comment($1)||$$
3733
$$
3734 11651 aaronmk
$_$;
3735
3736
3737
--
3738 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3739
--
3740
3741
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3742
    LANGUAGE sql STABLE
3743
    AS $_$
3744 12269 aaronmk
SELECT string_agg(cmd, '')
3745 11655 aaronmk
FROM
3746
(
3747
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3748
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3749
$$ ELSE '' END) AS cmd
3750
	FROM util.grants_users() f (user_)
3751
) s
3752
$_$;
3753
3754
3755
--
3756 12325 aaronmk
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3757
--
3758
3759 12670 aaronmk
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['c'::text, 'r'::text, 'v'::text]) RETURNS SETOF regclass
3760 12325 aaronmk
    LANGUAGE sql STABLE
3761
    AS $_$
3762
SELECT oid FROM pg_class
3763
WHERE relkind = ANY($3) AND relname ~ $1
3764
AND util.schema_matches(util.schema(relnamespace), $2)
3765
ORDER BY relname
3766
$_$;
3767
3768
3769
--
3770 13478 aaronmk
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
3771
--
3772
3773
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
3774
    LANGUAGE sql STABLE
3775
    AS $_$
3776 13480 aaronmk
SELECT util.mk_set_comment($1, util.comment($1))
3777 13478 aaronmk
$_$;
3778
3779
3780
--
3781 12592 aaronmk
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3782
--
3783
3784
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3785
    LANGUAGE sql STABLE
3786
    AS $_$
3787
SELECT oid
3788
FROM pg_type
3789
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3790
ORDER BY typname
3791
$_$;
3792
3793
3794
--
3795 12305 aaronmk
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3796
--
3797
3798 12385 aaronmk
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3799 12305 aaronmk
    LANGUAGE sql STABLE
3800
    AS $_$
3801 12385 aaronmk
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3802 12305 aaronmk
$_$;
3803
3804
3805
--
3806 12384 aaronmk
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3807
--
3808
3809
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3810
    LANGUAGE sql IMMUTABLE
3811
    AS $_$
3812
SELECT '^'||util.regexp_quote($1)||'$'
3813
$_$;
3814
3815
3816
--
3817 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3818 8144 aaronmk
--
3819
3820
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3821 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
3822 8144 aaronmk
    AS $_$
3823
DECLARE
3824
    hstore hstore;
3825
BEGIN
3826
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3827
        table_||$$))$$ INTO STRICT hstore;
3828
    RETURN hstore;
3829
END;
3830
$_$;
3831
3832
3833
--
3834 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3835
--
3836
3837
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3838 12446 aaronmk
    LANGUAGE sql STABLE
3839 10184 aaronmk
    AS $_$
3840
SELECT COUNT(*) > 0 FROM pg_constraint
3841
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3842
$_$;
3843
3844
3845
--
3846
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3847
--
3848
3849 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3850
gets whether a status flag is set by the presence of a table constraint
3851
';
3852 10184 aaronmk
3853
3854
--
3855 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3856
--
3857
3858
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3859 12446 aaronmk
    LANGUAGE sql
3860 10182 aaronmk
    AS $_$
3861
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3862
||quote_ident($2)||$$ CHECK (true)$$)
3863
$_$;
3864
3865
3866
--
3867
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3868
--
3869
3870 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3871
stores a status flag by the presence of a table constraint.
3872
idempotent.
3873
';
3874 10182 aaronmk
3875
3876
--
3877 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3878
--
3879
3880
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3881 12446 aaronmk
    LANGUAGE sql STABLE
3882 10185 aaronmk
    AS $_$
3883
SELECT util.table_flag__get($1, 'nulls_mapped')
3884
$_$;
3885
3886
3887
--
3888
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3889
--
3890
3891 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3892
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3893
';
3894 10185 aaronmk
3895
3896
--
3897 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3898
--
3899
3900
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3901 12446 aaronmk
    LANGUAGE sql
3902 10183 aaronmk
    AS $_$
3903
SELECT util.table_flag__set($1, 'nulls_mapped')
3904
$_$;
3905
3906
3907
--
3908
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3909
--
3910
3911 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3912
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3913
idempotent.
3914
';
3915 10183 aaronmk
3916
3917
--
3918 12652 aaronmk
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3919
--
3920
3921
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3922
    LANGUAGE sql
3923
    AS $_$
3924
-- save data before truncating main table
3925
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3926
3927
-- repopulate main table w/ copies column
3928
SELECT util.truncate($1);
3929
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3930
SELECT util.populate_table($1, $$
3931
SELECT (table_).*, copies
3932
FROM (
3933
	SELECT table_, COUNT(*) AS copies
3934
	FROM pg_temp.__copy table_
3935
	GROUP BY table_
3936
) s
3937
$$);
3938
3939
-- delete temp table so it doesn't stay around until end of connection
3940
SELECT util.drop_table('pg_temp.__copy');
3941
$_$;
3942
3943
3944
--
3945 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3946 8088 aaronmk
--
3947
3948
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3949
    LANGUAGE plpgsql STRICT
3950
    AS $_$
3951
DECLARE
3952
    row record;
3953
BEGIN
3954 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3955 8088 aaronmk
    LOOP
3956
        IF row.global_name != row.name THEN
3957
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3958
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3959
        END IF;
3960
    END LOOP;
3961
END;
3962
$_$;
3963
3964
3965
--
3966 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3967 8088 aaronmk
--
3968
3969 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3970
idempotent
3971
';
3972 8088 aaronmk
3973
3974
--
3975 12874 aaronmk
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3976 10365 aaronmk
--
3977
3978 12874 aaronmk
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
3979 12446 aaronmk
    LANGUAGE sql
3980 10365 aaronmk
    AS $_$
3981 12874 aaronmk
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
3982 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
3983
$_$;
3984
3985
3986
--
3987 12874 aaronmk
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
3988 10365 aaronmk
--
3989
3990 12874 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass, force boolean) IS '
3991
trims table_ to include only columns in the original data
3992
3993
by default, cascadingly drops dependent columns so that they don''t prevent
3994
trim() from succeeding. note that this requires the dependent columns to then be
3995
manually re-created.
3996
3997
idempotent
3998 12235 aaronmk
';
3999 10365 aaronmk
4000
4001
--
4002 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4003 8142 aaronmk
--
4004
4005
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4006
    LANGUAGE plpgsql STRICT
4007
    AS $_$
4008
BEGIN
4009
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4010
END;
4011
$_$;
4012
4013
4014
--
4015 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4016 8142 aaronmk
--
4017
4018 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4019
idempotent
4020
';
4021 8142 aaronmk
4022
4023
--
4024 12357 aaronmk
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4025
--
4026
4027
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4028
    LANGUAGE sql IMMUTABLE
4029
    AS $_$
4030 12361 aaronmk
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4031 12362 aaronmk
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4032 12357 aaronmk
$_$;
4033
4034
4035
--
4036 13135 aaronmk
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4037
--
4038
4039
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4040
    LANGUAGE plpgsql IMMUTABLE
4041
    AS $$
4042
BEGIN
4043
	/* need explicit cast because some types not implicitly-castable, and also
4044
	to make the cast happen inside the try block. (*implicit* casts to the
4045
	return type happen at the end of the function, outside any block.) */
4046
	RETURN util.cast(value, ret_type_null);
4047
EXCEPTION
4048
WHEN data_exception THEN
4049
	PERFORM util.raise('WARNING', SQLERRM);
4050
	RETURN NULL;
4051
END;
4052
$$;
4053
4054
4055
--
4056
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4057
--
4058
4059
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4060
ret_type_null: NULL::ret_type
4061
';
4062
4063
4064
--
4065 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4066
--
4067
4068
CREATE FUNCTION try_create(sql text) RETURNS void
4069
    LANGUAGE plpgsql STRICT
4070
    AS $$
4071
BEGIN
4072 12658 aaronmk
	PERFORM util.eval(sql);
4073 8199 aaronmk
EXCEPTION
4074 12676 aaronmk
WHEN   not_null_violation
4075
		/* trying to add NOT NULL column to parent table, which cascades to
4076
		child table whose values for the new column will be NULL */
4077
	OR wrong_object_type -- trying to alter a view's columns
4078
	OR undefined_column
4079
	OR duplicate_column
4080
THEN NULL;
4081 12684 aaronmk
WHEN datatype_mismatch THEN
4082
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4083
	ELSE RAISE; -- rethrow
4084
	END IF;
4085 8199 aaronmk
END;
4086
$$;
4087
4088
4089
--
4090
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4091
--
4092
4093 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
4094
idempotent
4095
';
4096 8199 aaronmk
4097
4098
--
4099 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4100
--
4101
4102
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4103 12446 aaronmk
    LANGUAGE sql
4104 8209 aaronmk
    AS $_$
4105
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4106
$_$;
4107
4108
4109
--
4110
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4111
--
4112
4113 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4114
idempotent
4115
';
4116 8209 aaronmk
4117
4118
--
4119 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4120
--
4121
4122
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4123
    LANGUAGE sql IMMUTABLE
4124
    AS $_$
4125
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4126
$_$;
4127
4128
4129
--
4130 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4131
--
4132
4133 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4134
a type''s NOT NULL qualifier
4135
';
4136 10161 aaronmk
4137
4138
--
4139 12562 aaronmk
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4140
--
4141
4142
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4143 12590 aaronmk
    LANGUAGE sql STABLE
4144 12562 aaronmk
    AS $_$
4145
SELECT (attname::text, atttypid)::util.col_cast
4146
FROM pg_attribute
4147
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4148
ORDER BY attnum
4149
$_$;
4150
4151
4152
--
4153 12438 aaronmk
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4154
--
4155
4156
CREATE FUNCTION typeof(value anyelement) RETURNS text
4157
    LANGUAGE sql IMMUTABLE
4158
    AS $_$
4159
SELECT util.qual_name(pg_typeof($1))
4160
$_$;
4161
4162
4163
--
4164 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4165
--
4166
4167 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4168
    LANGUAGE plpgsql STABLE
4169 8185 aaronmk
    AS $_$
4170
DECLARE
4171
    type regtype;
4172
BEGIN
4173 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4174
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4175 8185 aaronmk
    RETURN type;
4176
END;
4177
$_$;
4178
4179
4180
--
4181 12490 aaronmk
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4182 12483 aaronmk
--
4183
4184 12490 aaronmk
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4185 12483 aaronmk
    LANGUAGE sql
4186
    AS $_$
4187 12488 aaronmk
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4188 12483 aaronmk
$_$;
4189
4190
4191
--
4192 12490 aaronmk
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4193 12488 aaronmk
--
4194
4195 12490 aaronmk
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4196 12488 aaronmk
auto-appends util to the search_path to enable use of util operators
4197
';
4198
4199
4200
--
4201 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4202
--
4203
4204
CREATE AGGREGATE all_same(anyelement) (
4205
    SFUNC = all_same_transform,
4206
    STYPE = anyarray,
4207
    FINALFUNC = all_same_final
4208
);
4209
4210
4211
--
4212
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4213
--
4214
4215 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
4216
includes NULLs in comparison
4217
';
4218 9959 aaronmk
4219
4220
--
4221 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4222 2595 aaronmk
--
4223
4224
CREATE AGGREGATE join_strs(text, text) (
4225 4052 aaronmk
    SFUNC = join_strs_transform,
4226 4010 aaronmk
    STYPE = text
4227 2595 aaronmk
);
4228
4229
4230 8147 aaronmk
--
4231 12423 aaronmk
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4232
--
4233
4234
CREATE OPERATOR %== (
4235
    PROCEDURE = "%==",
4236
    LEFTARG = anyelement,
4237
    RIGHTARG = anyelement
4238
);
4239
4240
4241
--
4242
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4243
--
4244
4245
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4246
returns whether the map-keys of the compared values are the same
4247
(mnemonic: % is the Perl symbol for a hash map)
4248
4249
should be overridden for types that store both keys and values
4250
4251
used in a FULL JOIN to select which columns to join on
4252
';
4253
4254
4255
--
4256 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4257 8147 aaronmk
--
4258
4259
CREATE OPERATOR -> (
4260
    PROCEDURE = map_get,
4261
    LEFTARG = regclass,
4262
    RIGHTARG = text
4263
);
4264
4265
4266 10308 aaronmk
--
4267
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4268
--
4269
4270
CREATE OPERATOR => (
4271
    PROCEDURE = hstore,
4272 10357 aaronmk
    LEFTARG = text[],
4273 10608 aaronmk
    RIGHTARG = text
4274 10308 aaronmk
);
4275
4276
4277
--
4278 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4279 10308 aaronmk
--
4280
4281 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
4282
usage: array[''key1'', ...]::text[] => ''value''
4283
';
4284 10308 aaronmk
4285
4286 10391 aaronmk
--
4287 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4288
--
4289
4290
CREATE OPERATOR ?*>= (
4291
    PROCEDURE = is_populated_more_often_than,
4292
    LEFTARG = anyelement,
4293
    RIGHTARG = anyelement
4294
);
4295
4296
4297
--
4298 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4299
--
4300
4301
CREATE OPERATOR ?>= (
4302
    PROCEDURE = is_more_complete_than,
4303
    LEFTARG = anyelement,
4304
    RIGHTARG = anyelement
4305
);
4306
4307
4308 11005 aaronmk
--
4309
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4310
--
4311
4312
CREATE OPERATOR ||% (
4313
    PROCEDURE = concat_esc,
4314
    LEFTARG = text,
4315
    RIGHTARG = text
4316
);
4317
4318
4319
--
4320
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4321
--
4322
4323 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
4324
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4325
';
4326 11005 aaronmk
4327
4328 2107 aaronmk
--
4329 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
4330 8140 aaronmk
--
4331
4332
CREATE TABLE map (
4333
    "from" text NOT NULL,
4334 8158 aaronmk
    "to" text,
4335
    filter text,
4336
    notes text
4337 8140 aaronmk
);
4338
4339
4340
--
4341 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4342
--
4343
4344
4345
4346
--
4347 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4348 8140 aaronmk
--
4349
4350
4351
4352
--
4353 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
4354 8140 aaronmk
--
4355
4356
ALTER TABLE ONLY map
4357 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4358 8140 aaronmk
4359
4360
--
4361 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
4362
--
4363
4364
ALTER TABLE ONLY map
4365
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4366
4367
4368
--
4369 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4370
--
4371
4372
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4373
4374
4375
--
4376 2136 aaronmk
-- PostgreSQL database dump complete
4377
--