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