Project

General

Profile

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