Project

General

Profile

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