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