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