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