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