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