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