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