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