Project

General

Profile

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