Project

General

Profile

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