Project

General

Profile

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