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