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