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