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