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 13139 aaronmk
	-- must happen *after* cast check, because NULL is not valid for some types
1925
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
1926 13136 aaronmk
	RETURN true;
1927
EXCEPTION
1928
WHEN data_exception THEN RETURN false;
1929
END;
1930
$$;
1931
1932
1933
--
1934
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1935
--
1936
1937
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
1938 13139 aaronmk
passes NULL through. however, if NULL is not valid for the type, false will be
1939
returned instead.
1940
1941 13136 aaronmk
ret_type_null: NULL::ret_type
1942
';
1943
1944
1945
--
1946 10137 aaronmk
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1947
--
1948
1949
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1950 12446 aaronmk
    LANGUAGE sql STABLE
1951 10137 aaronmk
    AS $_$
1952 12789 aaronmk
SELECT COALESCE(util.col_comment($1) LIKE '
1953
constant
1954
%', false)
1955 10137 aaronmk
$_$;
1956
1957
1958
--
1959 11659 aaronmk
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1960
--
1961
1962
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1963
    LANGUAGE sql IMMUTABLE
1964
    AS $_$
1965
SELECT util.array_length($1) = 0
1966
$_$;
1967
1968
1969
--
1970 12457 aaronmk
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1971
--
1972
1973
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1974
    LANGUAGE sql IMMUTABLE
1975
    AS $_$
1976
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1977
$_$;
1978
1979
1980
--
1981 12451 aaronmk
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1982
--
1983
1984
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1985
    LANGUAGE sql IMMUTABLE
1986
    AS $_$
1987
SELECT upper(util.first_word($1)) = ANY(
1988
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1989
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1990
)
1991
$_$;
1992
1993
1994
--
1995 10391 aaronmk
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1996
--
1997
1998
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1999
    LANGUAGE sql IMMUTABLE
2000
    AS $_$
2001
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2002
$_$;
2003
2004
2005
--
2006 10613 aaronmk
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2007
--
2008
2009
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2010
    LANGUAGE sql IMMUTABLE
2011
    AS $_$
2012
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2013
$_$;
2014
2015
2016
--
2017 12480 aaronmk
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
2018
--
2019
2020
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2021
    LANGUAGE sql IMMUTABLE
2022
    AS $_$
2023
SELECT upper(util.first_word($1)) = 'SET'
2024
$_$;
2025
2026
2027
--
2028 12330 aaronmk
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
2029
--
2030
2031
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2032 12332 aaronmk
    LANGUAGE sql STABLE
2033 12330 aaronmk
    AS $_$
2034
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2035
$_$;
2036
2037
2038
--
2039 12329 aaronmk
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2040
--
2041
2042
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2043 12332 aaronmk
    LANGUAGE sql STABLE
2044 12329 aaronmk
    AS $_$
2045
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2046
$_$;
2047
2048
2049
--
2050 8183 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2051 4009 aaronmk
--
2052
2053 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2054 12444 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
2055 4009 aaronmk
    AS $_$
2056 4054 aaronmk
SELECT $1 || $3 || $2
2057 2595 aaronmk
$_$;
2058
2059
2060
--
2061 12444 aaronmk
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2062
--
2063
2064
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2065
must be declared STRICT to use the special handling of STRICT aggregating functions
2066
';
2067
2068
2069
--
2070 12436 aaronmk
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2071
--
2072
2073
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2074
    LANGUAGE sql IMMUTABLE
2075
    AS $_$
2076
SELECT $1 -- compare on the entire value
2077
$_$;
2078
2079
2080
--
2081 10989 aaronmk
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2082 10985 aaronmk
--
2083
2084 10989 aaronmk
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2085 10985 aaronmk
    LANGUAGE sql IMMUTABLE
2086
    AS $_$
2087 10989 aaronmk
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2088 10985 aaronmk
$_$;
2089
2090
2091
--
2092 12275 aaronmk
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2093
--
2094
2095
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2096
    LANGUAGE sql IMMUTABLE
2097
    AS $_$
2098
SELECT ltrim($1, $$
2099
$$)
2100
$_$;
2101
2102
2103
--
2104 10110 aaronmk
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2105
--
2106
2107
CREATE FUNCTION map_filter_insert() RETURNS trigger
2108
    LANGUAGE plpgsql
2109
    AS $$
2110
BEGIN
2111
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2112
	RETURN new;
2113
END;
2114
$$;
2115
2116
2117
--
2118 8183 aaronmk
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2119 8146 aaronmk
--
2120
2121
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2122
    LANGUAGE plpgsql STABLE STRICT
2123
    AS $_$
2124
DECLARE
2125
    value text;
2126
BEGIN
2127
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2128 8149 aaronmk
        INTO value USING key;
2129 8146 aaronmk
    RETURN value;
2130
END;
2131
$_$;
2132
2133
2134
--
2135 10358 aaronmk
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2136 10325 aaronmk
--
2137
2138 10358 aaronmk
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2139 10353 aaronmk
    LANGUAGE sql IMMUTABLE
2140 10325 aaronmk
    AS $_$
2141 10374 aaronmk
SELECT util._map(util.nulls_map($1), $2)
2142 10325 aaronmk
$_$;
2143
2144
2145
--
2146 10359 aaronmk
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2147
--
2148
2149 12235 aaronmk
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
2150
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
2151 10359 aaronmk
2152
[1] inlining of function calls, which is different from constant folding
2153
[2] _map()''s profiling query
2154
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2155
and map_nulls()''s profiling query
2156
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2157 10375 aaronmk
both take ~920 ms.
2158 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.
2159
';
2160 10359 aaronmk
2161
2162
--
2163 8183 aaronmk
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2164 8150 aaronmk
--
2165
2166
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2167
    LANGUAGE plpgsql STABLE STRICT
2168
    AS $_$
2169
BEGIN
2170
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2171
END;
2172
$_$;
2173
2174
2175
--
2176 12228 aaronmk
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2177
--
2178
2179 12262 aaronmk
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2180 12228 aaronmk
    LANGUAGE sql
2181
    AS $_$
2182 12262 aaronmk
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2183 12321 aaronmk
$$||util.ltrim_nl($2));
2184
-- make sure the created table has the correct estimated row count
2185
SELECT util.analyze_($1);
2186 12470 aaronmk
2187
SELECT util.append_comment($1, '
2188
contents generated from:
2189
'||util.ltrim_nl($2)||';
2190
');
2191 12228 aaronmk
$_$;
2192
2193
2194
--
2195 12262 aaronmk
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2196 12228 aaronmk
--
2197
2198 12262 aaronmk
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2199 12235 aaronmk
idempotent
2200
';
2201 12228 aaronmk
2202
2203
--
2204 12234 aaronmk
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2205
--
2206
2207 12262 aaronmk
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2208 12234 aaronmk
    LANGUAGE sql
2209
    AS $_$
2210
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2211
$_$;
2212
2213
2214
--
2215 12262 aaronmk
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2216 12234 aaronmk
--
2217
2218 12262 aaronmk
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2219 12235 aaronmk
idempotent
2220
';
2221 12234 aaronmk
2222
2223
--
2224 8190 aaronmk
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2225
--
2226
2227
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2228 12446 aaronmk
    LANGUAGE sql
2229 8190 aaronmk
    AS $_$
2230 10135 aaronmk
SELECT util.create_if_not_exists($$
2231
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2232 8190 aaronmk
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2233 10135 aaronmk
||quote_literal($2)||$$;
2234 12235 aaronmk
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2235
constant
2236
';
2237 10135 aaronmk
$$)
2238 8190 aaronmk
$_$;
2239
2240
2241
--
2242
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2243
--
2244
2245 12235 aaronmk
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2246
idempotent
2247
';
2248 8190 aaronmk
2249
2250
--
2251 10296 aaronmk
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2252 8187 aaronmk
--
2253
2254 10296 aaronmk
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2255 8187 aaronmk
    LANGUAGE plpgsql STRICT
2256
    AS $_$
2257
DECLARE
2258
    type regtype = util.typeof(expr, col.table_::text::regtype);
2259
    col_name_sql text = quote_ident(col.name);
2260
BEGIN
2261 10296 aaronmk
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2262
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2263 8187 aaronmk
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2264
$$||expr||$$;
2265
$$);
2266
END;
2267
$_$;
2268
2269
2270
--
2271 10296 aaronmk
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2272 8188 aaronmk
--
2273
2274 12235 aaronmk
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2275
idempotent
2276
';
2277 8188 aaronmk
2278
2279
--
2280 12554 aaronmk
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2281 12475 aaronmk
--
2282
2283 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
2284 12475 aaronmk
    LANGUAGE sql IMMUTABLE
2285
    AS $_$
2286
SELECT
2287 12478 aaronmk
$$SELECT
2288 12554 aaronmk
$$||$3||$$
2289 12555 aaronmk
FROM      $$||$1||$$ left_
2290 12554 aaronmk
FULL JOIN $$||$2||$$ right_
2291
ON $$||$4||$$
2292
WHERE $$||$5||$$
2293 12475 aaronmk
ORDER BY left_, right_
2294
$$
2295
$_$;
2296
2297
2298
--
2299 12564 aaronmk
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2300
--
2301
2302
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2303 12591 aaronmk
    LANGUAGE sql
2304 12564 aaronmk
    AS $_$
2305 12570 aaronmk
-- keys()
2306 12564 aaronmk
SELECT util.mk_keys_func($1, ARRAY(
2307
SELECT col FROM util.typed_cols($1) col
2308
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2309 12570 aaronmk
));
2310
2311 12571 aaronmk
-- values_()
2312 12570 aaronmk
SELECT util.mk_keys_func($1, COALESCE(
2313
	NULLIF(ARRAY(
2314
	SELECT col FROM util.typed_cols($1) col
2315
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2316
	), ARRAY[]::util.col_cast[])
2317
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2318 12571 aaronmk
, 'values_');
2319 12564 aaronmk
$_$;
2320
2321
2322
--
2323 12569 aaronmk
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2324 12561 aaronmk
--
2325
2326 12569 aaronmk
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2327 12591 aaronmk
    LANGUAGE sql
2328 12561 aaronmk
    AS $_$
2329 12567 aaronmk
SELECT util.create_if_not_exists($$
2330 12577 aaronmk
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2331
($$||util.mk_typed_cols_list($2)||$$);
2332 12671 aaronmk
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2333
autogenerated
2334
';
2335 12594 aaronmk
$$);
2336 12577 aaronmk
2337 12594 aaronmk
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2338
$_$;
2339
2340
2341
--
2342
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2343
--
2344
2345
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2346
    LANGUAGE sql
2347
    AS $_$
2348
SELECT util.create_if_not_exists($$
2349 12581 aaronmk
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2350 12577 aaronmk
||util.qual_name($1)||$$)
2351 12594 aaronmk
  RETURNS $$||util.qual_name($2)||$$ AS
2352 12561 aaronmk
$BODY1$
2353 12577 aaronmk
SELECT ROW($$||
2354 12594 aaronmk
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2355
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2356 12561 aaronmk
$BODY1$
2357
  LANGUAGE sql IMMUTABLE
2358
  COST 100;
2359 12594 aaronmk
$$);
2360 12561 aaronmk
$_$;
2361
2362
2363
--
2364 8183 aaronmk
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2365 8139 aaronmk
--
2366
2367
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2368 12446 aaronmk
    LANGUAGE sql
2369 8139 aaronmk
    AS $_$
2370 8183 aaronmk
SELECT util.create_if_not_exists($$
2371 8141 aaronmk
CREATE TABLE $$||$1||$$
2372 8139 aaronmk
(
2373 8183 aaronmk
    LIKE util.map INCLUDING ALL
2374 10110 aaronmk
);
2375
2376
CREATE TRIGGER map_filter_insert
2377
  BEFORE INSERT
2378
  ON $$||$1||$$
2379
  FOR EACH ROW
2380
  EXECUTE PROCEDURE util.map_filter_insert();
2381 8141 aaronmk
$$)
2382 8139 aaronmk
$_$;
2383
2384
2385
--
2386 12725 aaronmk
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2387
--
2388
2389
CREATE FUNCTION mk_not_null(text) RETURNS text
2390
    LANGUAGE sql IMMUTABLE
2391
    AS $_$
2392
SELECT COALESCE($1, '<NULL>')
2393
$_$;
2394
2395
2396
--
2397 12556 aaronmk
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2398
--
2399
2400
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2401
    LANGUAGE sql IMMUTABLE
2402
    AS $_$
2403 12559 aaronmk
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2404
util.qual_name((unnest).type), ''), '')
2405 12556 aaronmk
FROM unnest($1)
2406
$_$;
2407
2408
2409
--
2410 12236 aaronmk
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2411
--
2412
2413
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2414
    LANGUAGE sql IMMUTABLE
2415
    AS $_$
2416 12486 aaronmk
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2417 12236 aaronmk
$_$;
2418
2419
2420
--
2421 12486 aaronmk
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2422
--
2423
2424
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2425
auto-appends util to the search_path to enable use of util operators
2426
';
2427
2428
2429
--
2430 12467 aaronmk
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2431
--
2432
2433
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2434
    LANGUAGE sql IMMUTABLE
2435
    AS $_$
2436
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2437
$_$;
2438
2439
2440
--
2441 12466 aaronmk
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2442 12270 aaronmk
--
2443
2444 12466 aaronmk
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2445 12270 aaronmk
    LANGUAGE sql IMMUTABLE
2446
    AS $_$
2447 12432 aaronmk
/* debug_print_return_value() needed because this function is used with EXECUTE
2448
rather than util.eval() (in order to affect the calling function), so the
2449
search_path would not otherwise be printed */
2450 12487 aaronmk
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2451
||$$ search_path TO $$||$1
2452 12270 aaronmk
$_$;
2453
2454
2455
--
2456 10113 aaronmk
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2457
--
2458
2459
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2460 12446 aaronmk
    LANGUAGE sql
2461 10113 aaronmk
    AS $_$
2462 12240 aaronmk
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2463 10113 aaronmk
$_$;
2464
2465
2466
--
2467
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2468
--
2469
2470 12235 aaronmk
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2471
idempotent
2472
';
2473 10113 aaronmk
2474
2475
--
2476 11011 aaronmk
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2477
--
2478
2479
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2480
    LANGUAGE plpgsql STRICT
2481
    AS $_$
2482
DECLARE
2483
	view_qual_name text = util.qual_name(view_);
2484
BEGIN
2485
	EXECUTE $$
2486
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2487
  RETURNS SETOF $$||view_||$$ AS
2488
$BODY1$
2489
SELECT * FROM $$||view_qual_name||$$
2490
ORDER BY sort_col
2491
LIMIT $1 OFFSET $2
2492
$BODY1$
2493
  LANGUAGE sql STABLE
2494
  COST 100
2495
  ROWS 1000
2496
$$;
2497
2498
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2499
END;
2500
$_$;
2501
2502
2503
--
2504 8325 aaronmk
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2505
--
2506
2507
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2508
    LANGUAGE plpgsql STRICT
2509
    AS $_$
2510 10990 aaronmk
DECLARE
2511
	view_qual_name text = util.qual_name(view_);
2512
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2513 8325 aaronmk
BEGIN
2514
	EXECUTE $$
2515 10990 aaronmk
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2516
  RETURNS integer AS
2517
$BODY1$
2518
SELECT $$||quote_ident(row_num_col)||$$
2519
FROM $$||view_qual_name||$$
2520
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2521
LIMIT 1
2522
$BODY1$
2523
  LANGUAGE sql STABLE
2524
  COST 100;
2525
$$;
2526
2527
	EXECUTE $$
2528 8325 aaronmk
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2529
  RETURNS SETOF $$||view_||$$ AS
2530
$BODY1$
2531 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$
2532
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2533
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2534
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2535 10991 aaronmk
ORDER BY $$||quote_ident(row_num_col)||$$
2536 8325 aaronmk
$BODY1$
2537
  LANGUAGE sql STABLE
2538
  COST 100
2539
  ROWS 1000
2540
$$;
2541 11010 aaronmk
2542
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2543
END;
2544
$_$;
2545
2546
2547
--
2548
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2549
--
2550
2551
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2552
    LANGUAGE plpgsql STRICT
2553
    AS $_$
2554
DECLARE
2555
	view_qual_name text = util.qual_name(view_);
2556
BEGIN
2557 8326 aaronmk
	EXECUTE $$
2558
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2559
  RETURNS SETOF $$||view_||$$
2560
  SET enable_sort TO 'off'
2561
  AS
2562
$BODY1$
2563 10990 aaronmk
SELECT * FROM $$||view_qual_name||$$($2, $3)
2564 8326 aaronmk
$BODY1$
2565
  LANGUAGE sql STABLE
2566
  COST 100
2567
  ROWS 1000
2568
;
2569
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2570
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2571
If you want to run EXPLAIN and get expanded output, use the regular subset
2572
function instead. (When a config param is set on a function, EXPLAIN produces
2573
just a function scan.)
2574
';
2575
$$;
2576 8325 aaronmk
END;
2577
$_$;
2578
2579
2580
--
2581 11010 aaronmk
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2582
--
2583
2584 12235 aaronmk
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2585
creates subset function which turns off enable_sort
2586
';
2587 11010 aaronmk
2588
2589
--
2590 12576 aaronmk
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2591
--
2592
2593
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2594
    LANGUAGE sql IMMUTABLE
2595
    AS $_$
2596 12579 aaronmk
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2597 12576 aaronmk
util.qual_name((unnest).type), ', '), '')
2598
FROM unnest($1)
2599
$_$;
2600
2601
2602
--
2603 12242 aaronmk
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2604
--
2605
2606
CREATE FUNCTION name(table_ regclass) RETURNS text
2607
    LANGUAGE sql STABLE
2608
    AS $_$
2609
SELECT relname::text FROM pg_class WHERE oid = $1
2610
$_$;
2611
2612
2613
--
2614 8183 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2615 8083 aaronmk
--
2616
2617
CREATE FUNCTION name(type regtype) RETURNS text
2618 12446 aaronmk
    LANGUAGE sql STABLE
2619 8083 aaronmk
    AS $_$
2620
SELECT typname::text FROM pg_type WHERE oid = $1
2621
$_$;
2622
2623
2624
--
2625 12360 aaronmk
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2626 12355 aaronmk
--
2627
2628 12360 aaronmk
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2629 12355 aaronmk
    LANGUAGE sql IMMUTABLE
2630
    AS $_$
2631 12360 aaronmk
SELECT octet_length($1) >= util.namedatalen() - $2
2632 12355 aaronmk
$_$;
2633
2634
2635
--
2636 12354 aaronmk
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2637
--
2638
2639
CREATE FUNCTION namedatalen() RETURNS integer
2640
    LANGUAGE sql IMMUTABLE
2641
    AS $$
2642
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2643
$$;
2644
2645
2646
--
2647 9958 aaronmk
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2648
--
2649
2650
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2651
    LANGUAGE sql IMMUTABLE
2652
    AS $_$
2653 10329 aaronmk
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2654 9958 aaronmk
$_$;
2655
2656
2657
--
2658 9956 aaronmk
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2659
--
2660
2661
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2662 9957 aaronmk
    LANGUAGE sql IMMUTABLE
2663 9956 aaronmk
    AS $_$
2664
SELECT $1 IS NOT NULL
2665
$_$;
2666
2667
2668
--
2669 10373 aaronmk
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2670
--
2671
2672
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2673
    LANGUAGE sql IMMUTABLE
2674
    AS $_$
2675
SELECT util.hstore($1, NULL) || '*=>*'
2676
$_$;
2677
2678
2679
--
2680
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2681
--
2682
2683 12235 aaronmk
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2684
for use with _map()
2685
';
2686 10373 aaronmk
2687
2688
--
2689 10989 aaronmk
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2690 10984 aaronmk
--
2691
2692 10989 aaronmk
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2693 10984 aaronmk
    LANGUAGE sql IMMUTABLE
2694
    AS $_$
2695 10989 aaronmk
SELECT $2 + COALESCE($1, 0)
2696 10984 aaronmk
$_$;
2697
2698
2699
--
2700 12659 aaronmk
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2701
--
2702
2703
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2704
    LANGUAGE sql STABLE
2705
    AS $_$
2706
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2707
$_$;
2708
2709
2710
--
2711 12651 aaronmk
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2712
--
2713
2714
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2715
    LANGUAGE sql
2716
    AS $_$
2717
SELECT util.eval($$INSERT INTO $$||$1||$$
2718
$$||util.ltrim_nl($2));
2719
-- make sure the created table has the correct estimated row count
2720
SELECT util.analyze_($1);
2721
$_$;
2722
2723
2724
--
2725 12575 aaronmk
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2726
--
2727
2728
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2729
    LANGUAGE sql IMMUTABLE
2730
    AS $_$
2731
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2732
$_$;
2733
2734
2735
--
2736 12494 aaronmk
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2737
--
2738
2739
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2740
    LANGUAGE sql
2741
    AS $_$
2742
SELECT util.set_comment($1, concat($2, util.comment($1)))
2743
$_$;
2744
2745
2746
--
2747
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2748
--
2749
2750
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2751
comment: must start and end with a newline
2752
';
2753
2754
2755
--
2756 12260 aaronmk
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2757
--
2758
2759
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2760
    LANGUAGE sql IMMUTABLE
2761
    AS $_$
2762
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2763
$_$;
2764
2765
2766
--
2767 10988 aaronmk
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2768
--
2769
2770
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2771 12446 aaronmk
    LANGUAGE sql STABLE
2772 12267 aaronmk
    SET search_path TO pg_temp
2773 10988 aaronmk
    AS $_$
2774 12267 aaronmk
SELECT $1::text
2775 10988 aaronmk
$_$;
2776
2777
2778
--
2779 12267 aaronmk
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2780
--
2781
2782
CREATE FUNCTION qual_name(type regtype) RETURNS text
2783 12446 aaronmk
    LANGUAGE sql STABLE
2784 12267 aaronmk
    SET search_path TO pg_temp
2785
    AS $_$
2786
SELECT $1::text
2787
$_$;
2788
2789
2790
--
2791
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2792
--
2793
2794
COMMENT ON FUNCTION qual_name(type regtype) IS '
2795
a type''s schema-qualified name
2796
';
2797
2798
2799
--
2800 12268 aaronmk
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2801
--
2802
2803
CREATE FUNCTION qual_name(type unknown) RETURNS text
2804 12446 aaronmk
    LANGUAGE sql STABLE
2805 12268 aaronmk
    AS $_$
2806
SELECT util.qual_name($1::text::regtype)
2807
$_$;
2808
2809
2810
--
2811 12376 aaronmk
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2812
--
2813
2814
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2815
    LANGUAGE sql IMMUTABLE
2816
    AS $_$
2817
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2818
$_$;
2819
2820
2821
--
2822
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2823
--
2824
2825
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2826
    LANGUAGE sql IMMUTABLE
2827
    AS $_$
2828
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2829
$_$;
2830
2831
2832
--
2833 12371 aaronmk
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2834
--
2835
2836
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2837
    LANGUAGE sql IMMUTABLE
2838
    AS $_$
2839 12437 aaronmk
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2840 12371 aaronmk
$_$;
2841
2842
2843
--
2844 12530 aaronmk
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2845
--
2846
2847
CREATE FUNCTION raise(type text, msg text) RETURNS void
2848
    LANGUAGE sql IMMUTABLE
2849 12560 aaronmk
    AS $_X$
2850 12530 aaronmk
SELECT util.eval($$
2851
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2852
  RETURNS void AS
2853 12560 aaronmk
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2854
$__BODY1$
2855 12530 aaronmk
BEGIN
2856
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2857
END;
2858 12560 aaronmk
$__BODY1$
2859 12530 aaronmk
  LANGUAGE plpgsql IMMUTABLE
2860
  COST 100;
2861 12532 aaronmk
$$, verbose_ := false);
2862 12530 aaronmk
2863 12532 aaronmk
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2864 12560 aaronmk
$_X$;
2865 12530 aaronmk
2866
2867
--
2868 12533 aaronmk
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2869
--
2870
2871
COMMENT ON FUNCTION raise(type text, msg text) IS '
2872
type: a log level from
2873
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2874
or a condition name from
2875
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2876
';
2877
2878
2879
--
2880 12536 aaronmk
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2881 12311 aaronmk
--
2882
2883 12536 aaronmk
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2884 12441 aaronmk
    LANGUAGE sql IMMUTABLE
2885 12311 aaronmk
    AS $_$
2886 12536 aaronmk
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2887 12311 aaronmk
$_$;
2888
2889
2890
--
2891 10116 aaronmk
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2892
--
2893
2894
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2895
    LANGUAGE plpgsql IMMUTABLE STRICT
2896
    AS $$
2897
BEGIN
2898
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2899
END;
2900
$$;
2901
2902
2903
--
2904 11657 aaronmk
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2905
--
2906
2907
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2908
    LANGUAGE sql IMMUTABLE
2909
    AS $_$
2910
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2911
$_$;
2912
2913
2914
--
2915 12333 aaronmk
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2916
--
2917
2918
CREATE FUNCTION regexp_quote(str text) RETURNS text
2919
    LANGUAGE sql IMMUTABLE
2920
    AS $_$
2921
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2922
$_$;
2923
2924
2925
--
2926 12375 aaronmk
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2927
--
2928
2929
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2930
    LANGUAGE sql IMMUTABLE
2931
    AS $_$
2932
SELECT (CASE WHEN right($1, 1) = ')'
2933 12377 aaronmk
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2934 12375 aaronmk
$_$;
2935
2936
2937
--
2938 12344 aaronmk
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2939
--
2940
2941
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2942
    LANGUAGE sql STABLE
2943
    AS $_$
2944
SELECT util.relation_type(util.relation_type_char($1))
2945
$_$;
2946
2947
2948
--
2949 12340 aaronmk
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2950 12339 aaronmk
--
2951
2952 12340 aaronmk
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2953 12339 aaronmk
    LANGUAGE sql IMMUTABLE
2954
    AS $_$
2955 12593 aaronmk
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2956 12339 aaronmk
$_$;
2957
2958
2959
--
2960 12588 aaronmk
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2961
--
2962
2963
CREATE FUNCTION relation_type(type regtype) RETURNS text
2964
    LANGUAGE sql IMMUTABLE
2965
    AS $$
2966
SELECT 'TYPE'::text
2967
$$;
2968
2969
2970
--
2971 12341 aaronmk
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2972
--
2973
2974
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2975
    LANGUAGE sql STABLE
2976
    AS $_$
2977
SELECT relkind FROM pg_class WHERE oid = $1
2978
$_$;
2979
2980
2981
--
2982 12293 aaronmk
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2983
--
2984
2985
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2986
    LANGUAGE sql
2987
    AS $_$
2988
/* can't have in_table/out_table inherit from *each other*, because inheritance
2989
also causes the rows of the parent table to be included in the child table.
2990
instead, they need to inherit from a common, empty table. */
2991 12382 aaronmk
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2992
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2993 13098 aaronmk
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
2994 12293 aaronmk
SELECT util.inherit($2, $4);
2995
SELECT util.inherit($3, $4);
2996
2997
SELECT util.rematerialize_query($1, $$
2998
SELECT * FROM util.diff(
2999 12419 aaronmk
  $$||util.quote_typed($2)||$$
3000
, $$||util.quote_typed($3)||$$
3001 12293 aaronmk
, NULL::$$||$4||$$)
3002
$$);
3003 12303 aaronmk
3004
/* the table unfortunately cannot be *materialized* in human-readable form,
3005
because this would create column name collisions between the two sides */
3006 12495 aaronmk
SELECT util.prepend_comment($1, '
3007 12303 aaronmk
to view this table in human-readable form (with each side''s tuple column
3008
expanded to its component fields):
3009 12572 aaronmk
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3010 13092 aaronmk
3011
to display NULL values that are extra or missing:
3012
SELECT * FROM '||$1||';
3013 12303 aaronmk
');
3014 12293 aaronmk
$_$;
3015
3016
3017
--
3018
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3019
--
3020
3021
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3022
type_table (*required*): table to create as the shared base type
3023
';
3024
3025
3026
--
3027 12265 aaronmk
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3028
--
3029
3030
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3031
    LANGUAGE sql
3032
    AS $_$
3033
SELECT util.drop_table($1);
3034
SELECT util.materialize_query($1, $2);
3035
$_$;
3036
3037
3038
--
3039
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3040
--
3041
3042
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3043
idempotent, but repeats action each time
3044
';
3045
3046
3047
--
3048 12247 aaronmk
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3049
--
3050
3051 12262 aaronmk
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3052 12247 aaronmk
    LANGUAGE sql
3053
    AS $_$
3054
SELECT util.drop_table($1);
3055
SELECT util.materialize_view($1, $2);
3056
$_$;
3057
3058
3059
--
3060 12262 aaronmk
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3061 12247 aaronmk
--
3062
3063 12262 aaronmk
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3064 12247 aaronmk
idempotent, but repeats action each time
3065
';
3066
3067
3068
--
3069 8183 aaronmk
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3070 8137 aaronmk
--
3071
3072 8148 aaronmk
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3073 12446 aaronmk
    LANGUAGE sql
3074 8137 aaronmk
    AS $_$
3075 8212 aaronmk
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3076 8137 aaronmk
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3077 10309 aaronmk
FROM util.col_names($1::text::regtype) f (name);
3078
SELECT NULL::void; -- don't fold away functions called in previous query
3079 8137 aaronmk
$_$;
3080
3081
3082
--
3083 8183 aaronmk
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3084 8137 aaronmk
--
3085
3086 12235 aaronmk
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3087
idempotent
3088
';
3089 8137 aaronmk
3090
3091
--
3092 12349 aaronmk
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3093
--
3094
3095
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3096
    LANGUAGE sql
3097
    AS $_$
3098 12353 aaronmk
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3099
included in the debug SQL */
3100
SELECT util.rename_relation(util.qual_name($1), $2)
3101 12349 aaronmk
$_$;
3102
3103
3104
--
3105
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3106
--
3107
3108 12364 aaronmk
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3109 12349 aaronmk
    LANGUAGE sql
3110
    AS $_$
3111
/* 'ALTER TABLE can be used with views too'
3112
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3113 12363 aaronmk
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3114
||quote_ident($2))
3115 12349 aaronmk
$_$;
3116
3117
3118
--
3119 12364 aaronmk
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3120 12349 aaronmk
--
3121
3122 12364 aaronmk
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3123 12349 aaronmk
idempotent
3124
';
3125
3126
3127
--
3128 12358 aaronmk
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3129 12350 aaronmk
--
3130
3131 12358 aaronmk
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3132 12350 aaronmk
    LANGUAGE sql IMMUTABLE
3133
    AS $_$
3134 12358 aaronmk
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3135 12350 aaronmk
$_$;
3136
3137
3138
--
3139 12358 aaronmk
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3140
--
3141
3142
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3143
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
3144
';
3145
3146
3147
--
3148 10297 aaronmk
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3149
--
3150
3151
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3152 12446 aaronmk
    LANGUAGE sql
3153 10297 aaronmk
    AS $_$
3154 10596 aaronmk
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3155
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3156 10297 aaronmk
SELECT util.set_col_names($1, $2);
3157
$_$;
3158
3159
3160
--
3161
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3162
--
3163
3164 12235 aaronmk
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3165
idempotent.
3166
alters the names table, so it will need to be repopulated after running this function.
3167
';
3168 10297 aaronmk
3169
3170
--
3171 8183 aaronmk
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3172 8143 aaronmk
--
3173
3174
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3175 12446 aaronmk
    LANGUAGE sql
3176 8143 aaronmk
    AS $_$
3177 10152 aaronmk
SELECT util.drop_table($1);
3178 8183 aaronmk
SELECT util.mk_map_table($1);
3179 8143 aaronmk
$_$;
3180
3181
3182
--
3183 13096 aaronmk
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3184
--
3185
3186
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3187
    LANGUAGE sql
3188
    AS $_$
3189
SELECT util.drop_column($1, $2, force := true)
3190
$_$;
3191
3192
3193
--
3194 12356 aaronmk
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3195
--
3196
3197
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3198
    LANGUAGE sql IMMUTABLE
3199
    AS $_$
3200
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3201
$_$;
3202
3203
3204
--
3205 12473 aaronmk
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3206
--
3207
3208
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3209
    LANGUAGE sql IMMUTABLE
3210
    AS $_$
3211 12481 aaronmk
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3212
ELSE util.mk_set_search_path(for_printing := true)||$$;
3213
$$ END)||$1
3214 12473 aaronmk
$_$;
3215
3216
3217
--
3218 11652 aaronmk
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3219
--
3220
3221
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3222
    LANGUAGE plpgsql STRICT
3223
    AS $_$
3224
DECLARE
3225
	result text = NULL;
3226
BEGIN
3227
	BEGIN
3228
		result = util.show_create_view(view_);
3229
		PERFORM util.eval($$DROP VIEW $$||view_);
3230
	EXCEPTION
3231
		WHEN undefined_table THEN NULL;
3232
	END;
3233
	RETURN result;
3234
END;
3235
$_$;
3236
3237
3238
--
3239 11660 aaronmk
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3240
--
3241
3242
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3243
    LANGUAGE sql
3244
    AS $_$
3245 12269 aaronmk
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3246 11660 aaronmk
$_$;
3247
3248
3249
--
3250 12244 aaronmk
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3251
--
3252
3253
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3254
    LANGUAGE sql STABLE
3255
    AS $_$
3256
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3257
$_$;
3258
3259
3260
--
3261 12242 aaronmk
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3262
--
3263
3264
CREATE FUNCTION schema(table_ regclass) RETURNS text
3265
    LANGUAGE sql STABLE
3266
    AS $_$
3267 12245 aaronmk
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3268 12242 aaronmk
$_$;
3269
3270
3271
--
3272 10794 aaronmk
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3273
--
3274
3275
CREATE FUNCTION schema(type regtype) RETURNS text
3276
    LANGUAGE sql STABLE
3277
    AS $_$
3278 12245 aaronmk
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3279 10794 aaronmk
$_$;
3280
3281
3282
--
3283
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3284
--
3285
3286
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3287
    LANGUAGE sql STABLE
3288
    AS $_$
3289
SELECT util.schema(pg_typeof($1))
3290
$_$;
3291
3292
3293
--
3294 12134 aaronmk
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3295
--
3296
3297
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3298
    LANGUAGE sql STABLE
3299
    AS $_$
3300
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3301
$_$;
3302
3303
3304
--
3305 12135 aaronmk
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3306
--
3307
3308 12235 aaronmk
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3309
a schema bundle is a group of schemas with a common prefix
3310
';
3311 12135 aaronmk
3312
3313
--
3314
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3315
--
3316
3317
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3318
    LANGUAGE sql
3319
    AS $_$
3320
SELECT util.schema_rename(old_schema,
3321
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3322
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3323
SELECT NULL::void; -- don't fold away functions called in previous query
3324
$_$;
3325
3326
3327
--
3328
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3329
--
3330
3331
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3332
    LANGUAGE plpgsql
3333
    AS $$
3334
BEGIN
3335
	-- don't schema_bundle_rm() the schema_bundle to keep!
3336
	IF replace = with_ THEN RETURN; END IF;
3337
3338
	PERFORM util.schema_bundle_rm(replace);
3339
	PERFORM util.schema_bundle_rename(with_, replace);
3340
END;
3341
$$;
3342
3343
3344
--
3345
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3346
--
3347
3348
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3349
    LANGUAGE sql
3350
    AS $_$
3351
SELECT util.schema_rm(schema)
3352
FROM util.schema_bundle_get_schemas($1) f (schema);
3353
SELECT NULL::void; -- don't fold away functions called in previous query
3354
$_$;
3355
3356
3357
--
3358 12238 aaronmk
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3359 10795 aaronmk
--
3360
3361 12238 aaronmk
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3362 10795 aaronmk
    LANGUAGE sql STABLE
3363
    AS $_$
3364
SELECT quote_ident(util.schema($1))
3365
$_$;
3366
3367
3368
--
3369 12324 aaronmk
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3370
--
3371
3372
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3373 12334 aaronmk
    LANGUAGE sql IMMUTABLE
3374 12324 aaronmk
    AS $_$
3375
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3376
$_$;
3377
3378
3379
--
3380 12304 aaronmk
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3381
--
3382
3383
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3384
    LANGUAGE sql STABLE
3385
    AS $_$
3386
SELECT oid FROM pg_namespace WHERE nspname = $1
3387
$_$;
3388
3389
3390
--
3391 12504 aaronmk
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3392
--
3393
3394
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3395
    LANGUAGE sql IMMUTABLE
3396
    AS $_$
3397
SELECT util.schema_regexp(schema_anchor := $1)
3398
$_$;
3399
3400
3401
--
3402 12501 aaronmk
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3403
--
3404
3405
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3406
    LANGUAGE sql IMMUTABLE
3407
    AS $_$
3408
SELECT util.str_equality_regexp(util.schema($1))
3409
$_$;
3410
3411
3412
--
3413 12132 aaronmk
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3414
--
3415
3416
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3417
    LANGUAGE sql
3418
    AS $_$
3419
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3420
$_$;
3421
3422
3423
--
3424 12133 aaronmk
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3425
--
3426
3427
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3428
    LANGUAGE plpgsql
3429
    AS $$
3430
BEGIN
3431
	-- don't schema_rm() the schema to keep!
3432
	IF replace = with_ THEN RETURN; END IF;
3433
3434
	PERFORM util.schema_rm(replace);
3435
	PERFORM util.schema_rename(with_, replace);
3436
END;
3437
$$;
3438
3439
3440
--
3441 12132 aaronmk
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3442
--
3443
3444
CREATE FUNCTION schema_rm(schema text) RETURNS void
3445
    LANGUAGE sql
3446
    AS $_$
3447
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3448
$_$;
3449
3450
3451
--
3452 9825 aaronmk
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3453
--
3454
3455
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3456 12446 aaronmk
    LANGUAGE sql
3457 9825 aaronmk
    AS $_$
3458
SELECT util.eval(
3459
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3460
$_$;
3461
3462
3463
--
3464 8183 aaronmk
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3465 8153 aaronmk
--
3466
3467
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3468
    LANGUAGE plpgsql STRICT
3469
    AS $_$
3470
DECLARE
3471 8183 aaronmk
    old text[] = ARRAY(SELECT util.col_names(table_));
3472
    new text[] = ARRAY(SELECT util.map_values(names));
3473 8153 aaronmk
BEGIN
3474
    old = old[1:array_length(new, 1)]; -- truncate to same length
3475 10345 aaronmk
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3476
||$$ TO $$||quote_ident(value))
3477 10149 aaronmk
    FROM each(hstore(old, new))
3478
    WHERE value != key -- not same name
3479
    ;
3480 8153 aaronmk
END;
3481
$_$;
3482
3483
3484
--
3485 8183 aaronmk
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3486 8153 aaronmk
--
3487
3488 12235 aaronmk
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3489
idempotent
3490
';
3491 8153 aaronmk
3492
3493
--
3494 10145 aaronmk
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3495
--
3496
3497
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3498
    LANGUAGE plpgsql STRICT
3499
    AS $_$
3500
DECLARE
3501
	row_ util.map;
3502
BEGIN
3503 10715 aaronmk
	-- rename any metadata cols rather than re-adding them with new names
3504
	BEGIN
3505
		PERFORM util.set_col_names(table_, names);
3506
	EXCEPTION
3507
		WHEN array_subscript_error THEN -- selective suppress
3508
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3509
				-- metadata cols not yet added
3510 12568 aaronmk
			ELSE RAISE;
3511 10715 aaronmk
			END IF;
3512
	END;
3513
3514 10157 aaronmk
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3515 10145 aaronmk
	LOOP
3516 10147 aaronmk
		PERFORM util.mk_const_col((table_, row_."to"),
3517
			substring(row_."from" from 2));
3518 10145 aaronmk
	END LOOP;
3519
3520
	PERFORM util.set_col_names(table_, names);
3521
END;
3522
$_$;
3523
3524
3525
--
3526
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3527
--
3528
3529 12235 aaronmk
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3530
idempotent.
3531
the metadata mappings must be *last* in the names table.
3532
';
3533 10145 aaronmk
3534
3535
--
3536 8183 aaronmk
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3537 8107 aaronmk
--
3538
3539
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3540 12733 aaronmk
    LANGUAGE sql
3541 8107 aaronmk
    AS $_$
3542 12734 aaronmk
SELECT util.eval(COALESCE(
3543
$$ALTER TABLE $$||$1||$$
3544 12732 aaronmk
$$||(
3545
	SELECT
3546
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3547
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
3548
, $$)
3549
	FROM
3550
	(
3551
		SELECT
3552
		  quote_ident(col_name) AS col_name_sql
3553 12733 aaronmk
		, util.col_type(($1, col_name)) AS curr_type
3554 12732 aaronmk
		, type AS target_type
3555 12733 aaronmk
		FROM unnest($2)
3556 12732 aaronmk
	) s
3557
	WHERE curr_type != target_type
3558 12734 aaronmk
), ''))
3559 8107 aaronmk
$_$;
3560
3561
3562
--
3563 8183 aaronmk
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3564 8107 aaronmk
--
3565
3566 12235 aaronmk
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3567
idempotent
3568
';
3569 8107 aaronmk
3570
3571
--
3572 12302 aaronmk
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3573
--
3574
3575
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3576 12446 aaronmk
    LANGUAGE sql
3577 12302 aaronmk
    AS $_$
3578
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3579
$_$;
3580
3581
3582
--
3583 12482 aaronmk
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3584
--
3585
3586
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3587
    LANGUAGE sql
3588
    AS $_$
3589
SELECT util.eval(util.mk_set_search_path($1, $2))
3590
$_$;
3591
3592
3593
--
3594 11651 aaronmk
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3595
--
3596
3597
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3598
    LANGUAGE sql STABLE
3599
    AS $_$
3600 11656 aaronmk
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3601
$$||util.show_grants_for($1)
3602 11651 aaronmk
$_$;
3603
3604
3605
--
3606 11655 aaronmk
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3607
--
3608
3609
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3610
    LANGUAGE sql STABLE
3611
    AS $_$
3612 12269 aaronmk
SELECT string_agg(cmd, '')
3613 11655 aaronmk
FROM
3614
(
3615
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3616
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3617
$$ ELSE '' END) AS cmd
3618
	FROM util.grants_users() f (user_)
3619
) s
3620
$_$;
3621
3622
3623
--
3624 12325 aaronmk
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3625
--
3626
3627 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
3628 12325 aaronmk
    LANGUAGE sql STABLE
3629
    AS $_$
3630
SELECT oid FROM pg_class
3631
WHERE relkind = ANY($3) AND relname ~ $1
3632
AND util.schema_matches(util.schema(relnamespace), $2)
3633
ORDER BY relname
3634
$_$;
3635
3636
3637
--
3638 12592 aaronmk
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3639
--
3640
3641
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3642
    LANGUAGE sql STABLE
3643
    AS $_$
3644
SELECT oid
3645
FROM pg_type
3646
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3647
ORDER BY typname
3648
$_$;
3649
3650
3651
--
3652 12305 aaronmk
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3653
--
3654
3655 12385 aaronmk
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3656 12305 aaronmk
    LANGUAGE sql STABLE
3657
    AS $_$
3658 12385 aaronmk
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3659 12305 aaronmk
$_$;
3660
3661
3662
--
3663 12384 aaronmk
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3664
--
3665
3666
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3667
    LANGUAGE sql IMMUTABLE
3668
    AS $_$
3669
SELECT '^'||util.regexp_quote($1)||'$'
3670
$_$;
3671
3672
3673
--
3674 8183 aaronmk
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3675 8144 aaronmk
--
3676
3677
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3678 8145 aaronmk
    LANGUAGE plpgsql STABLE STRICT
3679 8144 aaronmk
    AS $_$
3680
DECLARE
3681
    hstore hstore;
3682
BEGIN
3683
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3684
        table_||$$))$$ INTO STRICT hstore;
3685
    RETURN hstore;
3686
END;
3687
$_$;
3688
3689
3690
--
3691 10184 aaronmk
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3692
--
3693
3694
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3695 12446 aaronmk
    LANGUAGE sql STABLE
3696 10184 aaronmk
    AS $_$
3697
SELECT COUNT(*) > 0 FROM pg_constraint
3698
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3699
$_$;
3700
3701
3702
--
3703
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3704
--
3705
3706 12235 aaronmk
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3707
gets whether a status flag is set by the presence of a table constraint
3708
';
3709 10184 aaronmk
3710
3711
--
3712 10182 aaronmk
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3713
--
3714
3715
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3716 12446 aaronmk
    LANGUAGE sql
3717 10182 aaronmk
    AS $_$
3718
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3719
||quote_ident($2)||$$ CHECK (true)$$)
3720
$_$;
3721
3722
3723
--
3724
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3725
--
3726
3727 12235 aaronmk
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3728
stores a status flag by the presence of a table constraint.
3729
idempotent.
3730
';
3731 10182 aaronmk
3732
3733
--
3734 10185 aaronmk
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3735
--
3736
3737
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3738 12446 aaronmk
    LANGUAGE sql STABLE
3739 10185 aaronmk
    AS $_$
3740
SELECT util.table_flag__get($1, 'nulls_mapped')
3741
$_$;
3742
3743
3744
--
3745
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3746
--
3747
3748 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3749
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3750
';
3751 10185 aaronmk
3752
3753
--
3754 10183 aaronmk
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3755
--
3756
3757
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3758 12446 aaronmk
    LANGUAGE sql
3759 10183 aaronmk
    AS $_$
3760
SELECT util.table_flag__set($1, 'nulls_mapped')
3761
$_$;
3762
3763
3764
--
3765
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3766
--
3767
3768 12235 aaronmk
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3769
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3770
idempotent.
3771
';
3772 10183 aaronmk
3773
3774
--
3775 12652 aaronmk
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3776
--
3777
3778
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3779
    LANGUAGE sql
3780
    AS $_$
3781
-- save data before truncating main table
3782
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3783
3784
-- repopulate main table w/ copies column
3785
SELECT util.truncate($1);
3786
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3787
SELECT util.populate_table($1, $$
3788
SELECT (table_).*, copies
3789
FROM (
3790
	SELECT table_, COUNT(*) AS copies
3791
	FROM pg_temp.__copy table_
3792
	GROUP BY table_
3793
) s
3794
$$);
3795
3796
-- delete temp table so it doesn't stay around until end of connection
3797
SELECT util.drop_table('pg_temp.__copy');
3798
$_$;
3799
3800
3801
--
3802 8183 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3803 8088 aaronmk
--
3804
3805
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3806
    LANGUAGE plpgsql STRICT
3807
    AS $_$
3808
DECLARE
3809
    row record;
3810
BEGIN
3811 8183 aaronmk
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3812 8088 aaronmk
    LOOP
3813
        IF row.global_name != row.name THEN
3814
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3815
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3816
        END IF;
3817
    END LOOP;
3818
END;
3819
$_$;
3820
3821
3822
--
3823 8183 aaronmk
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3824 8088 aaronmk
--
3825
3826 12235 aaronmk
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3827
idempotent
3828
';
3829 8088 aaronmk
3830
3831
--
3832 12874 aaronmk
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3833 10365 aaronmk
--
3834
3835 12874 aaronmk
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
3836 12446 aaronmk
    LANGUAGE sql
3837 10365 aaronmk
    AS $_$
3838 12874 aaronmk
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
3839 10365 aaronmk
SELECT NULL::void; -- don't fold away functions called in previous query
3840
$_$;
3841
3842
3843
--
3844 12874 aaronmk
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
3845 10365 aaronmk
--
3846
3847 12874 aaronmk
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass, force boolean) IS '
3848
trims table_ to include only columns in the original data
3849
3850
by default, cascadingly drops dependent columns so that they don''t prevent
3851
trim() from succeeding. note that this requires the dependent columns to then be
3852
manually re-created.
3853
3854
idempotent
3855 12235 aaronmk
';
3856 10365 aaronmk
3857
3858
--
3859 8183 aaronmk
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3860 8142 aaronmk
--
3861
3862
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3863
    LANGUAGE plpgsql STRICT
3864
    AS $_$
3865
BEGIN
3866
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3867
END;
3868
$_$;
3869
3870
3871
--
3872 8183 aaronmk
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3873 8142 aaronmk
--
3874
3875 12235 aaronmk
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3876
idempotent
3877
';
3878 8142 aaronmk
3879
3880
--
3881 12357 aaronmk
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3882
--
3883
3884
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3885
    LANGUAGE sql IMMUTABLE
3886
    AS $_$
3887 12361 aaronmk
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3888 12362 aaronmk
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3889 12357 aaronmk
$_$;
3890
3891
3892
--
3893 13135 aaronmk
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
3894
--
3895
3896
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
3897
    LANGUAGE plpgsql IMMUTABLE
3898
    AS $$
3899
BEGIN
3900
	/* need explicit cast because some types not implicitly-castable, and also
3901
	to make the cast happen inside the try block. (*implicit* casts to the
3902
	return type happen at the end of the function, outside any block.) */
3903
	RETURN util.cast(value, ret_type_null);
3904
EXCEPTION
3905
WHEN data_exception THEN
3906
	PERFORM util.raise('WARNING', SQLERRM);
3907
	RETURN NULL;
3908
END;
3909
$$;
3910
3911
3912
--
3913
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
3914
--
3915
3916
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
3917
ret_type_null: NULL::ret_type
3918
';
3919
3920
3921
--
3922 8199 aaronmk
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3923
--
3924
3925
CREATE FUNCTION try_create(sql text) RETURNS void
3926
    LANGUAGE plpgsql STRICT
3927
    AS $$
3928
BEGIN
3929 12658 aaronmk
	PERFORM util.eval(sql);
3930 8199 aaronmk
EXCEPTION
3931 12676 aaronmk
WHEN   not_null_violation
3932
		/* trying to add NOT NULL column to parent table, which cascades to
3933
		child table whose values for the new column will be NULL */
3934
	OR wrong_object_type -- trying to alter a view's columns
3935
	OR undefined_column
3936
	OR duplicate_column
3937
THEN NULL;
3938 12684 aaronmk
WHEN datatype_mismatch THEN
3939
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
3940
	ELSE RAISE; -- rethrow
3941
	END IF;
3942 8199 aaronmk
END;
3943
$$;
3944
3945
3946
--
3947
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3948
--
3949
3950 12235 aaronmk
COMMENT ON FUNCTION try_create(sql text) IS '
3951
idempotent
3952
';
3953 8199 aaronmk
3954
3955
--
3956 8209 aaronmk
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3957
--
3958
3959
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3960 12446 aaronmk
    LANGUAGE sql
3961 8209 aaronmk
    AS $_$
3962
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3963
$_$;
3964
3965
3966
--
3967
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3968
--
3969
3970 12235 aaronmk
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3971
idempotent
3972
';
3973 8209 aaronmk
3974
3975
--
3976 8189 aaronmk
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3977
--
3978
3979
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3980
    LANGUAGE sql IMMUTABLE
3981
    AS $_$
3982
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3983
$_$;
3984
3985
3986
--
3987 10161 aaronmk
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3988
--
3989
3990 12235 aaronmk
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3991
a type''s NOT NULL qualifier
3992
';
3993 10161 aaronmk
3994
3995
--
3996 12562 aaronmk
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3997
--
3998
3999
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4000 12590 aaronmk
    LANGUAGE sql STABLE
4001 12562 aaronmk
    AS $_$
4002
SELECT (attname::text, atttypid)::util.col_cast
4003
FROM pg_attribute
4004
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4005
ORDER BY attnum
4006
$_$;
4007
4008
4009
--
4010 12438 aaronmk
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4011
--
4012
4013
CREATE FUNCTION typeof(value anyelement) RETURNS text
4014
    LANGUAGE sql IMMUTABLE
4015
    AS $_$
4016
SELECT util.qual_name(pg_typeof($1))
4017
$_$;
4018
4019
4020
--
4021 8185 aaronmk
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4022
--
4023
4024 10160 aaronmk
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4025
    LANGUAGE plpgsql STABLE
4026 8185 aaronmk
    AS $_$
4027
DECLARE
4028
    type regtype;
4029
BEGIN
4030 10160 aaronmk
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4031
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4032 8185 aaronmk
    RETURN type;
4033
END;
4034
$_$;
4035
4036
4037
--
4038 12490 aaronmk
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4039 12483 aaronmk
--
4040
4041 12490 aaronmk
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4042 12483 aaronmk
    LANGUAGE sql
4043
    AS $_$
4044 12488 aaronmk
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4045 12483 aaronmk
$_$;
4046
4047
4048
--
4049 12490 aaronmk
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4050 12488 aaronmk
--
4051
4052 12490 aaronmk
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4053 12488 aaronmk
auto-appends util to the search_path to enable use of util operators
4054
';
4055
4056
4057
--
4058 9959 aaronmk
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4059
--
4060
4061
CREATE AGGREGATE all_same(anyelement) (
4062
    SFUNC = all_same_transform,
4063
    STYPE = anyarray,
4064
    FINALFUNC = all_same_final
4065
);
4066
4067
4068
--
4069
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4070
--
4071
4072 12235 aaronmk
COMMENT ON AGGREGATE all_same(anyelement) IS '
4073
includes NULLs in comparison
4074
';
4075 9959 aaronmk
4076
4077
--
4078 8183 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4079 2595 aaronmk
--
4080
4081
CREATE AGGREGATE join_strs(text, text) (
4082 4052 aaronmk
    SFUNC = join_strs_transform,
4083 4010 aaronmk
    STYPE = text
4084 2595 aaronmk
);
4085
4086
4087 8147 aaronmk
--
4088 12423 aaronmk
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4089
--
4090
4091
CREATE OPERATOR %== (
4092
    PROCEDURE = "%==",
4093
    LEFTARG = anyelement,
4094
    RIGHTARG = anyelement
4095
);
4096
4097
4098
--
4099
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4100
--
4101
4102
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4103
returns whether the map-keys of the compared values are the same
4104
(mnemonic: % is the Perl symbol for a hash map)
4105
4106
should be overridden for types that store both keys and values
4107
4108
used in a FULL JOIN to select which columns to join on
4109
';
4110
4111
4112
--
4113 8183 aaronmk
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4114 8147 aaronmk
--
4115
4116
CREATE OPERATOR -> (
4117
    PROCEDURE = map_get,
4118
    LEFTARG = regclass,
4119
    RIGHTARG = text
4120
);
4121
4122
4123 10308 aaronmk
--
4124
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4125
--
4126
4127
CREATE OPERATOR => (
4128
    PROCEDURE = hstore,
4129 10357 aaronmk
    LEFTARG = text[],
4130 10608 aaronmk
    RIGHTARG = text
4131 10308 aaronmk
);
4132
4133
4134
--
4135 10608 aaronmk
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4136 10308 aaronmk
--
4137
4138 12235 aaronmk
COMMENT ON OPERATOR => (text[], text) IS '
4139
usage: array[''key1'', ...]::text[] => ''value''
4140
';
4141 10308 aaronmk
4142
4143 10391 aaronmk
--
4144 10613 aaronmk
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4145
--
4146
4147
CREATE OPERATOR ?*>= (
4148
    PROCEDURE = is_populated_more_often_than,
4149
    LEFTARG = anyelement,
4150
    RIGHTARG = anyelement
4151
);
4152
4153
4154
--
4155 10391 aaronmk
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4156
--
4157
4158
CREATE OPERATOR ?>= (
4159
    PROCEDURE = is_more_complete_than,
4160
    LEFTARG = anyelement,
4161
    RIGHTARG = anyelement
4162
);
4163
4164
4165 11005 aaronmk
--
4166
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4167
--
4168
4169
CREATE OPERATOR ||% (
4170
    PROCEDURE = concat_esc,
4171
    LEFTARG = text,
4172
    RIGHTARG = text
4173
);
4174
4175
4176
--
4177
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4178
--
4179
4180 12235 aaronmk
COMMENT ON OPERATOR ||% (text, text) IS '
4181
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4182
';
4183 11005 aaronmk
4184
4185 2107 aaronmk
--
4186 8183 aaronmk
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace:
4187 8140 aaronmk
--
4188
4189
CREATE TABLE map (
4190
    "from" text NOT NULL,
4191 8158 aaronmk
    "to" text,
4192
    filter text,
4193
    notes text
4194 8140 aaronmk
);
4195
4196
4197
--
4198 11834 aaronmk
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4199
--
4200
4201
4202
4203
--
4204 8183 aaronmk
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4205 8140 aaronmk
--
4206
4207
4208
4209
--
4210 10342 aaronmk
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
4211 8140 aaronmk
--
4212
4213
ALTER TABLE ONLY map
4214 10342 aaronmk
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4215 8140 aaronmk
4216
4217
--
4218 10343 aaronmk
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace:
4219
--
4220
4221
ALTER TABLE ONLY map
4222
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4223
4224
4225
--
4226 10110 aaronmk
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4227
--
4228
4229
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4230
4231
4232
--
4233 2136 aaronmk
-- PostgreSQL database dump complete
4234
--