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