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