Project

General

Profile

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