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