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