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