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