Project

General

Profile

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