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