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