Project

General

Profile

1
--
2
-- PostgreSQL database dump
3
--
4

    
5
SET statement_timeout = 0;
6
SET lock_timeout = 0;
7
SET client_encoding = 'UTF8';
8
SET standard_conforming_strings = on;
9
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11

    
12
--
13
-- Name: util; Type: SCHEMA; Schema: -; Owner: -
14
--
15

    
16
CREATE SCHEMA util;
17

    
18

    
19
--
20
-- Name: SCHEMA util; Type: COMMENT; Schema: -; Owner: -
21
--
22

    
23
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

    
26
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
';
28

    
29

    
30
SET search_path = util, pg_catalog;
31

    
32
--
33
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
34
--
35

    
36
CREATE TYPE col_cast AS (
37
	col_name text,
38
	type regtype
39
);
40

    
41

    
42
--
43
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
44
--
45

    
46
CREATE TYPE col_ref AS (
47
	table_ regclass,
48
	name text
49
);
50

    
51

    
52
--
53
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
54
--
55

    
56
CREATE TYPE compass_dir AS ENUM (
57
    'N',
58
    'E',
59
    'S',
60
    'W'
61
);
62

    
63

    
64
--
65
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
66
--
67

    
68
CREATE TYPE datatype AS ENUM (
69
    'str',
70
    'float'
71
);
72

    
73

    
74
--
75
-- Name: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77

    
78
CREATE FUNCTION "%=="(left_ anyelement, right_ anyelement) RETURNS boolean
79
    LANGUAGE sql STABLE
80
    AS $_$
81
SELECT keys($1) = keys($2)
82
$_$;
83

    
84

    
85
--
86
-- 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
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
96
--
97

    
98
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
    LANGUAGE sql IMMUTABLE
100
    AS $_$
101
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
102
$_$;
103

    
104

    
105
--
106
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
107
--
108

    
109
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
    LANGUAGE sql IMMUTABLE
111
    AS $_$
112
SELECT bool_and(value)
113
FROM
114
(VALUES
115
      ($1)
116
    , ($2)
117
    , ($3)
118
    , ($4)
119
    , ($5)
120
)
121
AS v (value)
122
$_$;
123

    
124

    
125
--
126
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
127
--
128

    
129
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

    
133

    
134
--
135
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
136
--
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
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
156
--
157

    
158
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
159
    LANGUAGE sql IMMUTABLE
160
    AS $_$
161
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
FROM 
163
(
164
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
165
    UNION ALL
166
    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
)
169
matches (g)
170
$_$;
171

    
172

    
173
--
174
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
175
--
176

    
177
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
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
181
FROM
182
(VALUES
183
      ($1)
184
    , ($2/60)
185
    , ($3/60/60)
186
)
187
AS v (value)
188
$_$;
189

    
190

    
191
--
192
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
193
--
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
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
199
$_$;
200

    
201

    
202
--
203
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
204
--
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
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
215
--
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
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
228
--
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
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
239
--
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
SELECT util._if($1 != '', $2, $3)
245
$_$;
246

    
247

    
248
--
249
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
250
--
251

    
252
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
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
256
$_$;
257

    
258

    
259
--
260
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
261
--
262

    
263
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
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
267
$_$;
268

    
269

    
270
--
271
-- Name: _km_to_m(double precision); Type: FUNCTION; Schema: util; Owner: -
272
--
273

    
274
CREATE FUNCTION _km_to_m(value double precision) RETURNS double precision
275
    LANGUAGE sql IMMUTABLE
276
    AS $_$
277
SELECT $1*1000.
278
$_$;
279

    
280

    
281
--
282
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
283
--
284

    
285
CREATE FUNCTION _label(label text, value text) RETURNS text
286
    LANGUAGE sql IMMUTABLE
287
    AS $_$
288
SELECT coalesce($1 || ': ', '') || $2
289
$_$;
290

    
291

    
292
--
293
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
294
--
295

    
296
CREATE FUNCTION _lowercase(value text) RETURNS text
297
    LANGUAGE sql IMMUTABLE
298
    AS $_$
299
SELECT lower($1)
300
$_$;
301

    
302

    
303
--
304
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
305
--
306

    
307
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
308
    LANGUAGE plpgsql IMMUTABLE STRICT
309
    AS $$
310
DECLARE
311
    result value%TYPE := util._map(map, value::text)::unknown;
312
BEGIN
313
    RETURN result;
314
END;
315
$$;
316

    
317

    
318
--
319
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
320
--
321

    
322
CREATE FUNCTION _map(map hstore, value text) RETURNS text
323
    LANGUAGE plpgsql IMMUTABLE STRICT
324
    AS $$
325
DECLARE
326
    match text := map -> value;
327
BEGIN
328
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
329
        match := map -> '*'; -- use default entry
330
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
331
        END IF;
332
    END IF;
333
    
334
    -- Interpret result
335
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
336
    ELSIF match = '*' THEN RETURN value;
337
    ELSE RETURN match;
338
    END IF;
339
END;
340
$$;
341

    
342

    
343
--
344
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
345
--
346

    
347
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
348
    LANGUAGE sql IMMUTABLE
349
    AS $_$
350
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
351
$_$;
352

    
353

    
354
--
355
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
356
--
357

    
358
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
359
    LANGUAGE sql IMMUTABLE
360
    AS $_$
361
SELECT util.join_strs(value, '; ')
362
FROM
363
(
364
    SELECT *
365
    FROM
366
    (
367
        SELECT
368
        DISTINCT ON (value)
369
        *
370
        FROM
371
        (VALUES
372
              (1, $1)
373
            , (2, $2)
374
            , (3, $3)
375
            , (4, $4)
376
            , (5, $5)
377
            , (6, $6)
378
            , (7, $7)
379
            , (8, $8)
380
            , (9, $9)
381
            , (10, $10)
382
        )
383
        AS v (sort_order, value)
384
        WHERE value IS NOT NULL
385
    )
386
    AS v
387
    ORDER BY sort_order
388
)
389
AS v
390
$_$;
391

    
392

    
393
--
394
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
395
--
396

    
397
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
398
    LANGUAGE sql IMMUTABLE
399
    AS $_$
400
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
401
$_$;
402

    
403

    
404
--
405
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
406
--
407

    
408
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
409
    LANGUAGE sql IMMUTABLE
410
    AS $_$
411
SELECT util.join_strs(value, ' ')
412
FROM
413
(
414
    SELECT *
415
    FROM
416
    (
417
        SELECT
418
        DISTINCT ON (value)
419
        *
420
        FROM
421
        (VALUES
422
              (1, $1)
423
            , (2, $2)
424
            , (3, $3)
425
            , (4, $4)
426
            , (5, $5)
427
            , (6, $6)
428
            , (7, $7)
429
            , (8, $8)
430
            , (9, $9)
431
            , (10, $10)
432
        )
433
        AS v (sort_order, value)
434
        WHERE value IS NOT NULL
435
    )
436
    AS v
437
    ORDER BY sort_order
438
)
439
AS v
440
$_$;
441

    
442

    
443
--
444
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
445
--
446

    
447
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
448
    LANGUAGE sql IMMUTABLE
449
    AS $_$
450
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
451
$_$;
452

    
453

    
454
--
455
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
456
--
457

    
458
CREATE FUNCTION _not(value boolean) RETURNS boolean
459
    LANGUAGE sql IMMUTABLE
460
    AS $_$
461
SELECT NOT $1
462
$_$;
463

    
464

    
465
--
466
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
467
--
468

    
469
CREATE FUNCTION _now() RETURNS timestamp with time zone
470
    LANGUAGE sql STABLE
471
    AS $$
472
SELECT now()
473
$$;
474

    
475

    
476
--
477
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
478
--
479

    
480
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
481
    LANGUAGE sql IMMUTABLE
482
    AS $_$
483
SELECT util."_nullIf"($1, $2, $3::util.datatype)
484
$_$;
485

    
486

    
487
--
488
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
489
--
490

    
491
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
492
    LANGUAGE plpgsql IMMUTABLE
493
    AS $$
494
DECLARE
495
    type util.datatype NOT NULL := type; -- add NOT NULL
496
BEGIN
497
    IF type = 'str' THEN RETURN nullif(value::text, "null");
498
    -- Invalid value is ignored, but invalid null value generates error
499
    ELSIF type = 'float' THEN
500
        DECLARE
501
            -- Outside the try block so that invalid null value generates error
502
            "null" double precision := "null"::double precision;
503
        BEGIN
504
            RETURN nullif(value::double precision, "null");
505
        EXCEPTION
506
            WHEN data_exception THEN RETURN value; -- ignore invalid value
507
        END;
508
    END IF;
509
END;
510
$$;
511

    
512

    
513
--
514
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
515
--
516

    
517
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
518
    LANGUAGE sql IMMUTABLE
519
    AS $_$
520
SELECT bool_or(value)
521
FROM
522
(VALUES
523
      ($1)
524
    , ($2)
525
    , ($3)
526
    , ($4)
527
    , ($5)
528
)
529
AS v (value)
530
$_$;
531

    
532

    
533
--
534
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
535
--
536

    
537
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
538
_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.
539
';
540

    
541

    
542
--
543
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
544
--
545

    
546
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
547
    LANGUAGE sql IMMUTABLE
548
    AS $_$
549
SELECT $2 - $1
550
$_$;
551

    
552

    
553
--
554
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
555
--
556

    
557
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
558
    LANGUAGE sql IMMUTABLE
559
    AS $_$
560
SELECT regexp_split_to_table($1, $2)
561
$_$;
562

    
563

    
564
--
565
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
566
--
567

    
568
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
569
    LANGUAGE sql STABLE
570
    AS $_$
571
SELECT util.derived_cols($1, $2)
572
UNION
573
SELECT util.eval2set($$
574
SELECT col
575
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
576
JOIN $$||$2||$$ ON "to" = col
577
WHERE "from" LIKE ':%'
578
$$, NULL::text)
579
$_$;
580

    
581

    
582
--
583
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
584
--
585

    
586
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
587
gets table_''s added columns (all the columns not in the original data)
588
';
589

    
590

    
591
--
592
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
593
--
594

    
595
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
596
    LANGUAGE sql IMMUTABLE
597
    AS $_$
598
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
599
$_$;
600

    
601

    
602
--
603
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
604
--
605

    
606
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
607
    LANGUAGE plpgsql IMMUTABLE
608
    AS $$
609
DECLARE
610
	value_cmp         state%TYPE = ARRAY[value];
611
	state             state%TYPE = COALESCE(state, value_cmp);
612
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
613
BEGIN
614
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
615
END;
616
$$;
617

    
618

    
619
--
620
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
621
--
622

    
623
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
624
    LANGUAGE sql
625
    AS $_$
626
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
627
$_$;
628

    
629

    
630
--
631
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
632
--
633

    
634
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
635
    LANGUAGE sql
636
    AS $_$
637
SELECT util.set_comment($1, concat(util.comment($1), $2))
638
$_$;
639

    
640

    
641
--
642
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
643
--
644

    
645
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
646
comment: must start and end with a newline
647
';
648

    
649

    
650
--
651
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
652
--
653

    
654
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
655
    LANGUAGE sql IMMUTABLE
656
    AS $_$
657
SELECT pg_catalog.array_fill($1, ARRAY[$2])
658
$_$;
659

    
660

    
661
--
662
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
663
--
664

    
665
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
666
    LANGUAGE sql IMMUTABLE
667
    AS $_$
668
SELECT util.array_length($1, 1)
669
$_$;
670

    
671

    
672
--
673
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
674
--
675

    
676
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
677
    LANGUAGE sql IMMUTABLE
678
    AS $_$
679
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
680
$_$;
681

    
682

    
683
--
684
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
685
--
686

    
687
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
688
returns 0 instead of NULL for empty arrays
689
';
690

    
691

    
692
--
693
-- Name: array_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
694
--
695

    
696
CREATE FUNCTION array_reverse("array" anyarray) RETURNS anyarray
697
    LANGUAGE sql IMMUTABLE
698
    AS $_$
699
SELECT array(SELECT * FROM util.in_reverse($1))
700
$_$;
701

    
702

    
703
--
704
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
705
--
706

    
707
CREATE FUNCTION auto_rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
708
    LANGUAGE sql
709
    AS $_$
710
SELECT CASE WHEN util.freq_always_1($1, $2)
711
THEN util.rm_freq($1, $2)
712
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
713
END
714
$_$;
715

    
716

    
717
--
718
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
719
--
720

    
721
CREATE FUNCTION "cast"(value text, ret_type_null anyelement) RETURNS anyelement
722
    LANGUAGE plpgsql IMMUTABLE
723
    AS $$
724
/* must use LANGUAGE plpgsql because LANGUAGE sql does not assignment-cast the
725
return value, causing a type mismatch */
726
BEGIN
727
	-- will then be assignment-cast to return type via INOUT
728
	RETURN value::cstring;
729
END;
730
$$;
731

    
732

    
733
--
734
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
735
--
736

    
737
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
738
allows casting to an arbitrary type without eval()
739

    
740
usage:
741
SELECT util.cast(''value'', NULL::integer);
742

    
743
note that there does *not* need to be a cast from text to the output type,
744
because an INOUT cast is used instead
745
(http://www.postgresql.org/docs/9.3/static/sql-createcast.html#AEN69507)
746

    
747
ret_type_null: NULL::ret_type
748
';
749

    
750

    
751
--
752
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
753
--
754

    
755
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
756
    LANGUAGE sql STABLE
757
    AS $_$
758
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
759
$_$;
760

    
761

    
762
--
763
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
764
--
765

    
766
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
767
    LANGUAGE plpgsql STRICT
768
    AS $_$
769
BEGIN
770
    -- not yet clustered (ARRAY[] compares NULLs literally)
771
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
772
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
773
    END IF;
774
END;
775
$_$;
776

    
777

    
778
--
779
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
780
--
781

    
782
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
783
idempotent
784
';
785

    
786

    
787
--
788
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
789
--
790

    
791
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
792
    LANGUAGE sql IMMUTABLE
793
    AS $_$
794
SELECT value
795
FROM unnest($1) value
796
WHERE value IS NOT NULL
797
LIMIT 1
798
$_$;
799

    
800

    
801
--
802
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
803
--
804

    
805
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
806
uses:
807
* coalescing array elements or rows together
808
* forcing evaluation of all values of a COALESCE()
809
';
810

    
811

    
812
--
813
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
814
--
815

    
816
CREATE FUNCTION col__min(col col_ref) RETURNS integer
817
    LANGUAGE sql STABLE
818
    AS $_$
819
SELECT util.eval2val($$
820
SELECT $$||quote_ident($1.name)||$$
821
FROM $$||$1.table_||$$
822
ORDER BY $$||quote_ident($1.name)||$$ ASC
823
LIMIT 1
824
$$, NULL::integer)
825
$_$;
826

    
827

    
828
--
829
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
830
--
831

    
832
CREATE FUNCTION col_comment(col col_ref) RETURNS text
833
    LANGUAGE plpgsql STABLE STRICT
834
    AS $$
835
DECLARE
836
	comment text;
837
BEGIN
838
	SELECT description
839
	FROM pg_attribute
840
	LEFT JOIN pg_description ON objoid = attrelid
841
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
842
	WHERE attrelid = col.table_ AND attname = col.name
843
	INTO STRICT comment
844
	;
845
	RETURN comment;
846
EXCEPTION
847
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
848
END;
849
$$;
850

    
851

    
852
--
853
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
854
--
855

    
856
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
857
    LANGUAGE plpgsql STABLE STRICT
858
    AS $$
859
DECLARE
860
	default_sql text;
861
BEGIN
862
	SELECT adsrc
863
	FROM pg_attribute
864
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
865
	WHERE attrelid = col.table_ AND attname = col.name
866
	INTO STRICT default_sql
867
	;
868
	RETURN default_sql;
869
EXCEPTION
870
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
871
END;
872
$$;
873

    
874

    
875
--
876
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
877
--
878

    
879
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
880
    LANGUAGE sql STABLE
881
    AS $_$
882
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
883
$_$;
884

    
885

    
886
--
887
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
888
--
889

    
890
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
891
ret_type_null: NULL::ret_type
892
';
893

    
894

    
895
--
896
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
897
--
898

    
899
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
900
    LANGUAGE plpgsql STRICT
901
    AS $$
902
BEGIN
903
    PERFORM util.col_type(col);
904
    RETURN true;
905
EXCEPTION
906
    WHEN undefined_column THEN RETURN false;
907
END;
908
$$;
909

    
910

    
911
--
912
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
913
--
914

    
915
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
916
    LANGUAGE plpgsql STABLE STRICT
917
    AS $$
918
DECLARE
919
    prefix text := util.name(type)||'.';
920
BEGIN
921
    RETURN QUERY
922
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
923
        FROM util.col_names(type) f (name_);
924
END;
925
$$;
926

    
927

    
928
--
929
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
930
--
931

    
932
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
933
    LANGUAGE sql STABLE
934
    AS $_$
935
SELECT attname::text
936
FROM pg_attribute
937
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
938
ORDER BY attnum
939
$_$;
940

    
941

    
942
--
943
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
944
--
945

    
946
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
947
    LANGUAGE plpgsql STABLE STRICT
948
    AS $_$
949
BEGIN
950
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
951
END;
952
$_$;
953

    
954

    
955
--
956
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
957
--
958

    
959
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
960
    LANGUAGE plpgsql STABLE STRICT
961
    AS $$
962
DECLARE
963
    type regtype;
964
BEGIN
965
    SELECT atttypid FROM pg_attribute
966
    WHERE attrelid = col.table_ AND attname = col.name
967
    INTO STRICT type
968
    ;
969
    RETURN type;
970
EXCEPTION
971
    WHEN no_data_found THEN
972
        RAISE undefined_column USING MESSAGE =
973
            concat('undefined column: ', col.name);
974
END;
975
$$;
976

    
977

    
978
--
979
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
980
--
981

    
982
CREATE FUNCTION comment(element oid) RETURNS text
983
    LANGUAGE sql STABLE
984
    AS $_$
985
SELECT description FROM pg_description WHERE objoid = $1
986
$_$;
987

    
988

    
989
--
990
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
991
--
992

    
993
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
994
    LANGUAGE sql IMMUTABLE
995
    AS $_$
996
SELECT util.esc_name__append($2, $1)
997
$_$;
998

    
999

    
1000
--
1001
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
1002
--
1003

    
1004
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
1005
    LANGUAGE sql IMMUTABLE
1006
    AS $_$
1007
SELECT position($1 in $2) > 0 /*1-based offset*/
1008
$_$;
1009

    
1010

    
1011
--
1012
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1013
--
1014

    
1015
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1016
    LANGUAGE sql
1017
    AS $_$
1018
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1019
$_$;
1020

    
1021

    
1022
--
1023
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1024
--
1025

    
1026
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1027
    LANGUAGE sql
1028
    AS $_$
1029
SELECT util.materialize_view($2, $1)
1030
$_$;
1031

    
1032

    
1033
--
1034
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
1035
--
1036

    
1037
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
1038
    LANGUAGE plpgsql STRICT
1039
    AS $$
1040
BEGIN
1041
	PERFORM util.eval(sql);
1042
EXCEPTION
1043
WHEN   duplicate_table
1044
	OR duplicate_object -- eg. constraint
1045
	OR duplicate_column
1046
	OR duplicate_function
1047
THEN NULL;
1048
WHEN invalid_table_definition THEN
1049
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1050
	ELSE RAISE;
1051
	END IF;
1052
END;
1053
$$;
1054

    
1055

    
1056
--
1057
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
1058
--
1059

    
1060
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
1061
idempotent
1062
';
1063

    
1064

    
1065
--
1066
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1067
--
1068

    
1069
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1070
    LANGUAGE sql STABLE
1071
    AS $$
1072
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1073
$$;
1074

    
1075

    
1076
--
1077
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1078
--
1079

    
1080
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1081
    LANGUAGE sql IMMUTABLE
1082
    AS $_$
1083
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1084
$_$;
1085

    
1086

    
1087
--
1088
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1089
--
1090

    
1091
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1092
    LANGUAGE sql IMMUTABLE
1093
    AS $_$
1094
SELECT util.debug_print_value('returns: ', $1, $2);
1095
SELECT $1;
1096
$_$;
1097

    
1098

    
1099
--
1100
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1101
--
1102

    
1103
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1104
    LANGUAGE sql IMMUTABLE
1105
    AS $_$
1106
/* newline before so the query starts at the beginning of the line.
1107
newline after to visually separate queries from one another. */
1108
SELECT util.raise('NOTICE', $$
1109
$$||util.runnable_sql($1)||$$
1110
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1111
$_$;
1112

    
1113

    
1114
--
1115
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1116
--
1117

    
1118
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1119
    LANGUAGE sql IMMUTABLE
1120
    AS $_$
1121
SELECT util.raise('NOTICE', concat($1,
1122
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1123
$$)
1124
$_$;
1125

    
1126

    
1127
--
1128
-- Name: debug_print_var(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1129
--
1130

    
1131
CREATE FUNCTION debug_print_var(var text, value anyelement, encode boolean DEFAULT false) RETURNS void
1132
    LANGUAGE sql IMMUTABLE
1133
    AS $_$
1134
/* can't use EXECUTE in the caller because "No substitution of PL/pgSQL
1135
variables is done on the computed command string"
1136
(http://www.postgresql.org/docs/9.3/static/plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN) */
1137
SELECT util.debug_print_value($1||' = ', $2, $3)
1138
$_$;
1139

    
1140

    
1141
--
1142
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1143
--
1144

    
1145
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1146
    LANGUAGE sql STABLE
1147
    AS $_$
1148
SELECT util.eval2set($$
1149
SELECT col
1150
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1151
LEFT JOIN $$||$2||$$ ON "to" = col
1152
WHERE "from" IS NULL
1153
$$, NULL::text)
1154
$_$;
1155

    
1156

    
1157
--
1158
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1159
--
1160

    
1161
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1162
gets table_''s derived columns (all the columns not in the names table)
1163
';
1164

    
1165

    
1166
--
1167
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1168
--
1169

    
1170
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1171
    LANGUAGE sql
1172
    AS $_$
1173
-- create a diff when the # of copies of a row differs between the tables
1174
SELECT util.to_freq($1);
1175
SELECT util.to_freq($2);
1176
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1177

    
1178
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1179
$_$;
1180

    
1181

    
1182
--
1183
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1184
--
1185

    
1186
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1187
usage:
1188
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1189

    
1190
col_type_null (*required*): NULL::shared_base_type
1191
';
1192

    
1193

    
1194
--
1195
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1196
--
1197

    
1198
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
1199
    LANGUAGE plpgsql
1200
    SET search_path TO pg_temp
1201
    AS $_$
1202
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1203
changes of search_path (schema elements are bound at inline time rather than
1204
runtime) */
1205
/* function option search_path is needed to limit the effects of
1206
`SET LOCAL search_path` to the current function */
1207
BEGIN
1208
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1209
	
1210
	PERFORM util.mk_keys_func(pg_typeof($3));
1211
	RETURN QUERY
1212
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1213
$$/* need to explicitly cast each side to the return type because this does not
1214
happen automatically even when an implicit cast is available */
1215
  left_::$$||util.typeof($3)||$$
1216
, right_::$$||util.typeof($3)
1217
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1218
the *same* base type, *even though* this is optional when using a custom %== */
1219
, util._if($4, $$true/*= CROSS JOIN*/$$,
1220
$$ left_::$$||util.typeof($3)||$$
1221
%== right_::$$||util.typeof($3)||$$
1222
	-- refer to EXPLAIN output for expansion of %==$$
1223
)
1224
,     $$         left_::$$||util.typeof($3)||$$
1225
IS DISTINCT FROM right_::$$||util.typeof($3)
1226
), $3)
1227
	;
1228
END;
1229
$_$;
1230

    
1231

    
1232
--
1233
-- 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: -
1234
--
1235

    
1236
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1237
col_type_null (*required*): NULL::col_type
1238
single_row: whether the tables consist of a single row, which should be
1239
	displayed side-by-side
1240

    
1241
to match up rows using a subset of the columns, create a custom keys() function
1242
which returns this subset as a record:
1243
-- note that OUT parameters for the returned fields are *not* needed
1244
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1245
  RETURNS record AS
1246
$BODY$
1247
SELECT ($1.key_field_0, $1.key_field_1)
1248
$BODY$
1249
  LANGUAGE sql IMMUTABLE
1250
  COST 100;
1251

    
1252

    
1253
to run EXPLAIN on the FULL JOIN query:
1254
# run this function
1255
# look for a NOTICE containing the expanded query that it ran
1256
# run EXPLAIN on this expanded query
1257
';
1258

    
1259

    
1260
--
1261
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1262
--
1263

    
1264
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
1265
    LANGUAGE sql
1266
    AS $_$
1267
SELECT * FROM util.diff($1::text, $2::text, $3,
1268
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1269
$_$;
1270

    
1271

    
1272
--
1273
-- 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: -
1274
--
1275

    
1276
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1277
helper function used by diff(regclass, regclass)
1278

    
1279
usage:
1280
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1281

    
1282
col_type_null (*required*): NULL::shared_base_type
1283
';
1284

    
1285

    
1286
--
1287
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1288
--
1289

    
1290
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1291
    LANGUAGE sql
1292
    AS $_$
1293
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1294
$_$;
1295

    
1296

    
1297
--
1298
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1299
--
1300

    
1301
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1302
idempotent
1303
';
1304

    
1305

    
1306
--
1307
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1308
--
1309

    
1310
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1311
    LANGUAGE sql
1312
    AS $_$
1313
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1314
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1315
$_$;
1316

    
1317

    
1318
--
1319
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1320
--
1321

    
1322
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1323
idempotent
1324
';
1325

    
1326

    
1327
--
1328
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1329
--
1330

    
1331
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1332
    LANGUAGE sql
1333
    AS $_$
1334
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1335
SELECT NULL::void; -- don't fold away functions called in previous query
1336
$_$;
1337

    
1338

    
1339
--
1340
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1341
--
1342

    
1343
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1344
idempotent
1345
';
1346

    
1347

    
1348
--
1349
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1350
--
1351

    
1352
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1353
    LANGUAGE sql
1354
    AS $_$
1355
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1356
included in the debug SQL */
1357
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1358
$_$;
1359

    
1360

    
1361
--
1362
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1363
--
1364

    
1365
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1366
    LANGUAGE sql
1367
    AS $_$
1368
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1369
||util._if($3, $$ CASCADE$$, ''::text))
1370
$_$;
1371

    
1372

    
1373
--
1374
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1375
--
1376

    
1377
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1378
idempotent
1379
';
1380

    
1381

    
1382
--
1383
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1384
--
1385

    
1386
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1387
    LANGUAGE sql
1388
    AS $_$
1389
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1390
$_$;
1391

    
1392

    
1393
--
1394
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1395
--
1396

    
1397
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1398
    LANGUAGE sql
1399
    AS $_$
1400
SELECT util.debug_print_func_call(util.quote_func_call(
1401
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1402
util.quote_typed($3)))
1403
;
1404
SELECT util.drop_relation(relation, $3)
1405
FROM util.show_relations_like($1, $2) relation
1406
;
1407
SELECT NULL::void; -- don't fold away functions called in previous query
1408
$_$;
1409

    
1410

    
1411
--
1412
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1413
--
1414

    
1415
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1416
    LANGUAGE sql
1417
    AS $_$
1418
SELECT util.drop_relation('TABLE', $1, $2)
1419
$_$;
1420

    
1421

    
1422
--
1423
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1424
--
1425

    
1426
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1427
idempotent
1428
';
1429

    
1430

    
1431
--
1432
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1433
--
1434

    
1435
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1436
    LANGUAGE sql
1437
    AS $_$
1438
SELECT util.drop_relation('VIEW', $1, $2)
1439
$_$;
1440

    
1441

    
1442
--
1443
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1444
--
1445

    
1446
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1447
idempotent
1448
';
1449

    
1450

    
1451
--
1452
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1453
--
1454

    
1455
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1456
    LANGUAGE sql IMMUTABLE
1457
    AS $_$
1458
SELECT util.array_fill($1, 0)
1459
$_$;
1460

    
1461

    
1462
--
1463
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1464
--
1465

    
1466
COMMENT ON FUNCTION empty_array(elem_type_null anyelement) IS '
1467
constructs proper empty 1-dimensional array whose dimensions are not NULL ( ''{}''::text[] does not do this)
1468
';
1469

    
1470

    
1471
--
1472
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1473
--
1474

    
1475
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1476
    LANGUAGE sql IMMUTABLE
1477
    AS $_$
1478
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1479
$_$;
1480

    
1481

    
1482
--
1483
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1484
--
1485

    
1486
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1487
    LANGUAGE sql IMMUTABLE
1488
    AS $_$
1489
SELECT regexp_replace($2, '("?)$', $1||'\1')
1490
$_$;
1491

    
1492

    
1493
--
1494
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1495
--
1496

    
1497
CREATE FUNCTION eval(queries text[]) RETURNS void
1498
    LANGUAGE sql
1499
    AS $_$
1500
SELECT util.eval(query) FROM unnest($1) query;
1501
SELECT NULL::void; -- don't fold away functions called in previous query
1502
$_$;
1503

    
1504

    
1505
--
1506
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1507
--
1508

    
1509
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1510
    LANGUAGE plpgsql
1511
    AS $$
1512
BEGIN
1513
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1514
	EXECUTE sql;
1515
END;
1516
$$;
1517

    
1518

    
1519
--
1520
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1521
--
1522

    
1523
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1524
    LANGUAGE plpgsql
1525
    AS $$
1526
BEGIN
1527
	PERFORM util.debug_print_sql(sql);
1528
	RETURN QUERY EXECUTE sql;
1529
END;
1530
$$;
1531

    
1532

    
1533
--
1534
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1535
--
1536

    
1537
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1538
col_type_null (*required*): NULL::col_type
1539
';
1540

    
1541

    
1542
--
1543
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1544
--
1545

    
1546
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1547
    LANGUAGE plpgsql
1548
    AS $$
1549
BEGIN
1550
	PERFORM util.debug_print_sql(sql);
1551
	RETURN QUERY EXECUTE sql;
1552
END;
1553
$$;
1554

    
1555

    
1556
--
1557
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1558
--
1559

    
1560
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1561
    LANGUAGE plpgsql
1562
    AS $$
1563
BEGIN
1564
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1565
	RETURN QUERY EXECUTE sql;
1566
END;
1567
$$;
1568

    
1569

    
1570
--
1571
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1572
--
1573

    
1574
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1575
    LANGUAGE plpgsql STABLE
1576
    AS $$
1577
DECLARE
1578
	ret_val ret_type_null%TYPE;
1579
BEGIN
1580
	PERFORM util.debug_print_sql(sql);
1581
	EXECUTE sql INTO STRICT ret_val;
1582
	RETURN ret_val;
1583
END;
1584
$$;
1585

    
1586

    
1587
--
1588
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1589
--
1590

    
1591
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1592
ret_type_null: NULL::ret_type
1593
';
1594

    
1595

    
1596
--
1597
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1598
--
1599

    
1600
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1601
    LANGUAGE sql
1602
    AS $_$
1603
SELECT util.eval2val($$SELECT $$||$1, $2)
1604
$_$;
1605

    
1606

    
1607
--
1608
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1609
--
1610

    
1611
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1612
ret_type_null: NULL::ret_type
1613
';
1614

    
1615

    
1616
--
1617
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1618
--
1619

    
1620
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1621
    LANGUAGE sql
1622
    AS $_$
1623
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1624
$_$;
1625

    
1626

    
1627
--
1628
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1629
--
1630

    
1631
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1632
sql: can be NULL, which will be passed through
1633
ret_type_null: NULL::ret_type
1634
';
1635

    
1636

    
1637
--
1638
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1639
--
1640

    
1641
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1642
    LANGUAGE sql STABLE
1643
    AS $_$
1644
SELECT col_name
1645
FROM unnest($2) s (col_name)
1646
WHERE util.col_exists(($1, col_name))
1647
$_$;
1648

    
1649

    
1650
--
1651
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1652
--
1653

    
1654
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1655
    LANGUAGE sql
1656
    AS $_$
1657
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1658
$_$;
1659

    
1660

    
1661
--
1662
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1663
--
1664

    
1665
CREATE FUNCTION explain2notice(sql text) RETURNS void
1666
    LANGUAGE sql
1667
    AS $_$
1668
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1669
$_$;
1670

    
1671

    
1672
--
1673
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1674
--
1675

    
1676
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1677
    LANGUAGE sql
1678
    AS $_$
1679
-- newline before and after to visually separate it from other debug info
1680
SELECT COALESCE($$
1681
EXPLAIN:
1682
$$||util.fold_explain_msg(util.explain2str($1))||$$
1683
$$, '')
1684
$_$;
1685

    
1686

    
1687
--
1688
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1689
--
1690

    
1691
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1692
    LANGUAGE plpgsql
1693
    AS $$
1694
BEGIN
1695
	RETURN util.explain2notice_msg(sql);
1696
EXCEPTION
1697
WHEN syntax_error THEN RETURN NULL; -- non-explainable query
1698
	/* don't use util.is_explainable() because the list provided by Postgres
1699
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1700
	excludes some query types that are in fact EXPLAIN-able */
1701
END;
1702
$$;
1703

    
1704

    
1705
--
1706
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1707
--
1708

    
1709
CREATE FUNCTION explain2str(sql text) RETURNS text
1710
    LANGUAGE sql
1711
    AS $_$
1712
SELECT util.join_strs(explain, $$
1713
$$) FROM util.explain($1)
1714
$_$;
1715

    
1716

    
1717
SET default_tablespace = '';
1718

    
1719
SET default_with_oids = false;
1720

    
1721
--
1722
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1723
--
1724

    
1725
CREATE TABLE explain (
1726
    line text NOT NULL
1727
);
1728

    
1729

    
1730
--
1731
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1732
--
1733

    
1734
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1735
    LANGUAGE sql
1736
    AS $_$
1737
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1738
$$||quote_nullable($1)||$$
1739
)$$)
1740
$_$;
1741

    
1742

    
1743
--
1744
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1745
--
1746

    
1747
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1748
usage:
1749
PERFORM util.explain2table($$
1750
query
1751
$$);
1752
';
1753

    
1754

    
1755
--
1756
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1757
--
1758

    
1759
CREATE FUNCTION first_word(str text) RETURNS text
1760
    LANGUAGE sql IMMUTABLE
1761
    AS $_$
1762
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1763
$_$;
1764

    
1765

    
1766
--
1767
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1768
--
1769

    
1770
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1771
    LANGUAGE sql IMMUTABLE
1772
    AS $_$
1773
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1774
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1775
) END
1776
$_$;
1777

    
1778

    
1779
--
1780
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1781
--
1782

    
1783
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1784
ensures that an array will always have proper non-NULL dimensions
1785
';
1786

    
1787

    
1788
--
1789
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
1790
--
1791

    
1792
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1793
    LANGUAGE sql IMMUTABLE
1794
    AS $_$
1795
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1796
$_$;
1797

    
1798

    
1799
--
1800
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1801
--
1802

    
1803
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1804
    LANGUAGE plpgsql
1805
    AS $_$
1806
DECLARE
1807
	PG_EXCEPTION_DETAIL text;
1808
	restore_views_info text[] = util.save_drop_views(users);
1809
BEGIN
1810
	PERFORM util.eval(cmd);
1811
	PERFORM util.restore_views(restore_views_info);
1812
EXCEPTION
1813
WHEN dependent_objects_still_exist THEN
1814
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1815
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1816
	users = array(SELECT * FROM util.regexp_matches_group(
1817
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$'));
1818
		-- will be in forward dependency order
1819
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
1820
	PERFORM util.debug_print_var('users', users);
1821
	IF util.is_empty(users) THEN RAISE; END IF;
1822
	PERFORM util.force_recreate(cmd, users);
1823
END;
1824
$_$;
1825

    
1826

    
1827
--
1828
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1829
--
1830

    
1831
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1832
idempotent
1833

    
1834
users: not necessary to provide this because it will be autopopulated
1835
';
1836

    
1837

    
1838
--
1839
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1840
--
1841

    
1842
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1843
    LANGUAGE plpgsql STRICT
1844
    AS $_$
1845
DECLARE
1846
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1847
$$||query;
1848
BEGIN
1849
	EXECUTE mk_view;
1850
EXCEPTION
1851
WHEN invalid_table_definition THEN
1852
	IF SQLERRM = 'cannot drop columns from view'
1853
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1854
	THEN
1855
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1856
		EXECUTE mk_view;
1857
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1858
	END IF;
1859
END;
1860
$_$;
1861

    
1862

    
1863
--
1864
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1865
--
1866

    
1867
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1868
idempotent
1869
';
1870

    
1871

    
1872
--
1873
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1874
--
1875

    
1876
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1877
    LANGUAGE sql STABLE
1878
    AS $_$
1879
SELECT util.eval2val(
1880
$$SELECT NOT EXISTS( -- there is no row that is != 1
1881
	SELECT NULL
1882
	FROM $$||$1||$$
1883
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1884
	LIMIT 1
1885
)
1886
$$, NULL::boolean)
1887
$_$;
1888

    
1889

    
1890
--
1891
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1892
--
1893

    
1894
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1895
    LANGUAGE sql STABLE
1896
    AS $_$
1897
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1898
$_$;
1899

    
1900

    
1901
--
1902
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1903
--
1904

    
1905
CREATE FUNCTION grants_users() RETURNS SETOF text
1906
    LANGUAGE sql IMMUTABLE
1907
    AS $$
1908
VALUES ('bien_read'), ('public_')
1909
$$;
1910

    
1911

    
1912
--
1913
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1914
--
1915

    
1916
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1917
    LANGUAGE sql IMMUTABLE
1918
    AS $_$
1919
SELECT substring($2 for length($1)) = $1
1920
$_$;
1921

    
1922

    
1923
--
1924
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1925
--
1926

    
1927
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1928
    LANGUAGE sql STABLE
1929
    AS $_$
1930
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1931
$_$;
1932

    
1933

    
1934
--
1935
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1936
--
1937

    
1938
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1939
    LANGUAGE sql IMMUTABLE
1940
    AS $_$
1941
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1942
$_$;
1943

    
1944

    
1945
--
1946
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1947
--
1948

    
1949
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1950
avoids repeating the same value for each key
1951
';
1952

    
1953

    
1954
--
1955
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1956
--
1957

    
1958
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1959
    LANGUAGE sql IMMUTABLE
1960
    AS $_$
1961
SELECT COALESCE($1, $2)
1962
$_$;
1963

    
1964

    
1965
--
1966
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1967
--
1968

    
1969
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1970
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1971
';
1972

    
1973

    
1974
--
1975
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
1976
--
1977

    
1978
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
1979
    LANGUAGE sql IMMUTABLE
1980
    AS $_$
1981
SELECT * FROM unnest($1) ORDER BY row_number() OVER () DESC
1982
$_$;
1983

    
1984

    
1985
--
1986
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1987
--
1988

    
1989
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1990
    LANGUAGE sql
1991
    AS $_$
1992
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1993
$_$;
1994

    
1995

    
1996
--
1997
-- Name: is_castable(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1998
--
1999

    
2000
CREATE FUNCTION is_castable(value text, ret_type_null anyelement) RETURNS boolean
2001
    LANGUAGE plpgsql IMMUTABLE
2002
    AS $$
2003
BEGIN
2004
	PERFORM util.cast(value, ret_type_null);
2005
	-- must happen *after* cast check, because NULL is not valid for some types
2006
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
2007
	RETURN true;
2008
EXCEPTION
2009
WHEN data_exception THEN RETURN false;
2010
END;
2011
$$;
2012

    
2013

    
2014
--
2015
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
2016
--
2017

    
2018
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
2019
passes NULL through. however, if NULL is not valid for the type, false will be
2020
returned instead.
2021

    
2022
ret_type_null: NULL::ret_type
2023
';
2024

    
2025

    
2026
--
2027
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
2028
--
2029

    
2030
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
2031
    LANGUAGE sql STABLE
2032
    AS $_$
2033
SELECT COALESCE(util.col_comment($1) LIKE '
2034
constant
2035
%', false)
2036
$_$;
2037

    
2038

    
2039
--
2040
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2041
--
2042

    
2043
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
2044
    LANGUAGE sql IMMUTABLE
2045
    AS $_$
2046
SELECT util.array_length($1) = 0
2047
$_$;
2048

    
2049

    
2050
--
2051
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
2052
--
2053

    
2054
CREATE FUNCTION is_explain(sql text) RETURNS boolean
2055
    LANGUAGE sql IMMUTABLE
2056
    AS $_$
2057
SELECT upper(util.first_word($1)) = 'EXPLAIN'
2058
$_$;
2059

    
2060

    
2061
--
2062
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
2063
--
2064

    
2065
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
2066
    LANGUAGE sql IMMUTABLE
2067
    AS $_$
2068
SELECT upper(util.first_word($1)) = ANY(
2069
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
2070
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
2071
)
2072
$_$;
2073

    
2074

    
2075
--
2076
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2077
--
2078

    
2079
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
2080
    LANGUAGE sql IMMUTABLE
2081
    AS $_$
2082
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2083
$_$;
2084

    
2085

    
2086
--
2087
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2088
--
2089

    
2090
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2091
    LANGUAGE sql IMMUTABLE
2092
    AS $_$
2093
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2094
$_$;
2095

    
2096

    
2097
--
2098
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
2099
--
2100

    
2101
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2102
    LANGUAGE sql IMMUTABLE
2103
    AS $_$
2104
SELECT upper(util.first_word($1)) = 'SET'
2105
$_$;
2106

    
2107

    
2108
--
2109
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
2110
--
2111

    
2112
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2113
    LANGUAGE sql STABLE
2114
    AS $_$
2115
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2116
$_$;
2117

    
2118

    
2119
--
2120
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2121
--
2122

    
2123
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2124
    LANGUAGE sql STABLE
2125
    AS $_$
2126
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2127
$_$;
2128

    
2129

    
2130
--
2131
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2132
--
2133

    
2134
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2135
    LANGUAGE sql IMMUTABLE STRICT
2136
    AS $_$
2137
SELECT $1 || $3 || $2
2138
$_$;
2139

    
2140

    
2141
--
2142
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2143
--
2144

    
2145
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2146
must be declared STRICT to use the special handling of STRICT aggregating functions
2147
';
2148

    
2149

    
2150
--
2151
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2152
--
2153

    
2154
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2155
    LANGUAGE sql IMMUTABLE
2156
    AS $_$
2157
SELECT $1 -- compare on the entire value
2158
$_$;
2159

    
2160

    
2161
--
2162
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2163
--
2164

    
2165
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2166
    LANGUAGE sql IMMUTABLE
2167
    AS $_$
2168
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2169
$_$;
2170

    
2171

    
2172
--
2173
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2174
--
2175

    
2176
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2177
    LANGUAGE plpgsql
2178
    AS $$
2179
DECLARE
2180
	errors_ct integer = 0;
2181
	loop_var loop_type_null%TYPE;
2182
BEGIN
2183
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2184
	LOOP
2185
		BEGIN
2186
			EXECUTE loop_body_sql USING loop_var;
2187
		EXCEPTION
2188
		WHEN OTHERS THEN
2189
			errors_ct = errors_ct+1;
2190
			PERFORM util.raise_error_warning(SQLERRM);
2191
		END;
2192
	END LOOP;
2193
	IF errors_ct > 0 THEN
2194
		-- can't raise exception because this would roll back the transaction
2195
		PERFORM util.raise_error_warning('there were '||errors_ct
2196
			||' errors: see the WARNINGs for details');
2197
	END IF;
2198
END;
2199
$$;
2200

    
2201

    
2202
--
2203
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2204
--
2205

    
2206
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2207
    LANGUAGE sql IMMUTABLE
2208
    AS $_$
2209
SELECT ltrim($1, $$
2210
$$)
2211
$_$;
2212

    
2213

    
2214
--
2215
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2216
--
2217

    
2218
CREATE FUNCTION map_filter_insert() RETURNS trigger
2219
    LANGUAGE plpgsql
2220
    AS $$
2221
BEGIN
2222
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2223
	RETURN new;
2224
END;
2225
$$;
2226

    
2227

    
2228
--
2229
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2230
--
2231

    
2232
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2233
    LANGUAGE plpgsql STABLE STRICT
2234
    AS $_$
2235
DECLARE
2236
    value text;
2237
BEGIN
2238
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2239
        INTO value USING key;
2240
    RETURN value;
2241
END;
2242
$_$;
2243

    
2244

    
2245
--
2246
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2247
--
2248

    
2249
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2250
    LANGUAGE sql IMMUTABLE
2251
    AS $_$
2252
SELECT util._map(util.nulls_map($1), $2)
2253
$_$;
2254

    
2255

    
2256
--
2257
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2258
--
2259

    
2260
COMMENT ON FUNCTION map_nulls(nulls text[], value anyelement) IS '
2261
due to dynamic inlining[1], this is just as fast as util._map() which it wraps[2].
2262

    
2263
[1] inlining of function calls, which is different from constant folding
2264
[2] _map()''s profiling query
2265
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2266
and map_nulls()''s profiling query
2267
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2268
both take ~920 ms.
2269
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.
2270
';
2271

    
2272

    
2273
--
2274
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2275
--
2276

    
2277
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2278
    LANGUAGE plpgsql STABLE STRICT
2279
    AS $_$
2280
BEGIN
2281
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2282
END;
2283
$_$;
2284

    
2285

    
2286
--
2287
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2288
--
2289

    
2290
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2291
    LANGUAGE sql
2292
    AS $_$
2293
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2294
$$||util.ltrim_nl($2));
2295
-- make sure the created table has the correct estimated row count
2296
SELECT util.analyze_($1);
2297

    
2298
SELECT util.append_comment($1, '
2299
contents generated from:
2300
'||util.ltrim_nl(util.runnable_sql($2))||';
2301
');
2302
$_$;
2303

    
2304

    
2305
--
2306
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2307
--
2308

    
2309
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2310
idempotent
2311
';
2312

    
2313

    
2314
--
2315
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2316
--
2317

    
2318
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2319
    LANGUAGE sql
2320
    AS $_$
2321
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2322
$_$;
2323

    
2324

    
2325
--
2326
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2327
--
2328

    
2329
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2330
idempotent
2331
';
2332

    
2333

    
2334
--
2335
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2336
--
2337

    
2338
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2339
    LANGUAGE sql
2340
    AS $_$
2341
SELECT util.create_if_not_exists($$
2342
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2343
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2344
||quote_literal($2)||$$;
2345
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2346
constant
2347
';
2348
$$)
2349
$_$;
2350

    
2351

    
2352
--
2353
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2354
--
2355

    
2356
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2357
idempotent
2358
';
2359

    
2360

    
2361
--
2362
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2363
--
2364

    
2365
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2366
    LANGUAGE plpgsql STRICT
2367
    AS $_$
2368
DECLARE
2369
    type regtype = util.typeof(expr, col.table_::text::regtype);
2370
    col_name_sql text = quote_ident(col.name);
2371
BEGIN
2372
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2373
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2374
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2375
$$||expr||$$;
2376
$$);
2377
END;
2378
$_$;
2379

    
2380

    
2381
--
2382
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2383
--
2384

    
2385
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2386
idempotent
2387
';
2388

    
2389

    
2390
--
2391
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2392
--
2393

    
2394
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
2395
    LANGUAGE sql IMMUTABLE
2396
    AS $_$
2397
SELECT
2398
$$SELECT
2399
$$||$3||$$
2400
FROM      $$||$1||$$ left_
2401
FULL JOIN $$||$2||$$ right_
2402
ON $$||$4||$$
2403
WHERE $$||$5||$$
2404
ORDER BY left_, right_
2405
$$
2406
$_$;
2407

    
2408

    
2409
--
2410
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2411
--
2412

    
2413
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2414
    LANGUAGE sql
2415
    AS $_$
2416
-- keys()
2417
SELECT util.mk_keys_func($1, ARRAY(
2418
SELECT col FROM util.typed_cols($1) col
2419
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2420
));
2421

    
2422
-- values_()
2423
SELECT util.mk_keys_func($1, COALESCE(
2424
	NULLIF(ARRAY(
2425
	SELECT col FROM util.typed_cols($1) col
2426
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2427
	), ARRAY[]::util.col_cast[])
2428
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2429
, 'values_');
2430
$_$;
2431

    
2432

    
2433
--
2434
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2435
--
2436

    
2437
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2438
    LANGUAGE sql
2439
    AS $_$
2440
SELECT util.create_if_not_exists($$
2441
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2442
($$||util.mk_typed_cols_list($2)||$$);
2443
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2444
autogenerated
2445
';
2446
$$);
2447

    
2448
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2449
$_$;
2450

    
2451

    
2452
--
2453
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2454
--
2455

    
2456
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2457
    LANGUAGE sql
2458
    AS $_$
2459
SELECT util.create_if_not_exists($$
2460
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2461
||util.qual_name($1)||$$)
2462
  RETURNS $$||util.qual_name($2)||$$ AS
2463
$BODY1$
2464
SELECT ROW($$||
2465
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2466
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2467
$BODY1$
2468
  LANGUAGE sql IMMUTABLE
2469
  COST 100;
2470
$$);
2471
$_$;
2472

    
2473

    
2474
--
2475
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2476
--
2477

    
2478
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2479
    LANGUAGE sql
2480
    AS $_$
2481
SELECT util.create_if_not_exists($$
2482
CREATE TABLE $$||$1||$$
2483
(
2484
    LIKE util.map INCLUDING ALL
2485
);
2486

    
2487
CREATE TRIGGER map_filter_insert
2488
  BEFORE INSERT
2489
  ON $$||$1||$$
2490
  FOR EACH ROW
2491
  EXECUTE PROCEDURE util.map_filter_insert();
2492
$$)
2493
$_$;
2494

    
2495

    
2496
--
2497
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2498
--
2499

    
2500
CREATE FUNCTION mk_not_null(text) RETURNS text
2501
    LANGUAGE sql IMMUTABLE
2502
    AS $_$
2503
SELECT COALESCE($1, '<NULL>')
2504
$_$;
2505

    
2506

    
2507
--
2508
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2509
--
2510

    
2511
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2512
    LANGUAGE sql IMMUTABLE
2513
    AS $_$
2514
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2515
util.qual_name((unnest).type), ''), '')
2516
FROM unnest($1)
2517
$_$;
2518

    
2519

    
2520
--
2521
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2522
--
2523

    
2524
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2525
    LANGUAGE sql IMMUTABLE
2526
    AS $_$
2527
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2528
$_$;
2529

    
2530

    
2531
--
2532
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2533
--
2534

    
2535
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2536
auto-appends util to the search_path to enable use of util operators
2537
';
2538

    
2539

    
2540
--
2541
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2542
--
2543

    
2544
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2545
    LANGUAGE sql STABLE
2546
    AS $_$
2547
SELECT COALESCE($$COMMENT ON $$||util.relation_type($1)||$$ $$||$1||$$ IS $$
2548
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2549
$_$;
2550

    
2551

    
2552
--
2553
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2554
--
2555

    
2556
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2557
    LANGUAGE sql IMMUTABLE
2558
    AS $_$
2559
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2560
$_$;
2561

    
2562

    
2563
--
2564
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2565
--
2566

    
2567
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2568
    LANGUAGE sql IMMUTABLE
2569
    AS $_$
2570
/* debug_print_return_value() needed because this function is used with EXECUTE
2571
rather than util.eval() (in order to affect the calling function), so the
2572
search_path would not otherwise be printed */
2573
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2574
||$$ search_path TO $$||$1
2575
$_$;
2576

    
2577

    
2578
--
2579
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2580
--
2581

    
2582
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2583
    LANGUAGE sql
2584
    AS $_$
2585
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2586
$_$;
2587

    
2588

    
2589
--
2590
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2591
--
2592

    
2593
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2594
idempotent
2595
';
2596

    
2597

    
2598
--
2599
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2600
--
2601

    
2602
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2603
    LANGUAGE plpgsql STRICT
2604
    AS $_$
2605
DECLARE
2606
	view_qual_name text = util.qual_name(view_);
2607
BEGIN
2608
	EXECUTE $$
2609
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2610
  RETURNS SETOF $$||view_||$$ AS
2611
$BODY1$
2612
SELECT * FROM $$||view_qual_name||$$
2613
ORDER BY sort_col
2614
LIMIT $1 OFFSET $2
2615
$BODY1$
2616
  LANGUAGE sql STABLE
2617
  COST 100
2618
  ROWS 1000
2619
$$;
2620
	
2621
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2622
END;
2623
$_$;
2624

    
2625

    
2626
--
2627
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2628
--
2629

    
2630
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2631
    LANGUAGE plpgsql STRICT
2632
    AS $_$
2633
DECLARE
2634
	view_qual_name text = util.qual_name(view_);
2635
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2636
BEGIN
2637
	EXECUTE $$
2638
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2639
  RETURNS integer AS
2640
$BODY1$
2641
SELECT $$||quote_ident(row_num_col)||$$
2642
FROM $$||view_qual_name||$$
2643
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2644
LIMIT 1
2645
$BODY1$
2646
  LANGUAGE sql STABLE
2647
  COST 100;
2648
$$;
2649
	
2650
	EXECUTE $$
2651
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2652
  RETURNS SETOF $$||view_||$$ AS
2653
$BODY1$
2654
SELECT * FROM $$||view_qual_name||$$
2655
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2656
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2657
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2658
ORDER BY $$||quote_ident(row_num_col)||$$
2659
$BODY1$
2660
  LANGUAGE sql STABLE
2661
  COST 100
2662
  ROWS 1000
2663
$$;
2664
	
2665
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2666
END;
2667
$_$;
2668

    
2669

    
2670
--
2671
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2672
--
2673

    
2674
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2675
    LANGUAGE plpgsql STRICT
2676
    AS $_$
2677
DECLARE
2678
	view_qual_name text = util.qual_name(view_);
2679
BEGIN
2680
	EXECUTE $$
2681
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2682
  RETURNS SETOF $$||view_||$$
2683
  SET enable_sort TO 'off'
2684
  AS
2685
$BODY1$
2686
SELECT * FROM $$||view_qual_name||$$($2, $3)
2687
$BODY1$
2688
  LANGUAGE sql STABLE
2689
  COST 100
2690
  ROWS 1000
2691
;
2692
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2693
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2694
If you want to run EXPLAIN and get expanded output, use the regular subset
2695
function instead. (When a config param is set on a function, EXPLAIN produces
2696
just a function scan.)
2697
';
2698
$$;
2699
END;
2700
$_$;
2701

    
2702

    
2703
--
2704
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2705
--
2706

    
2707
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2708
creates subset function which turns off enable_sort
2709
';
2710

    
2711

    
2712
--
2713
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2714
--
2715

    
2716
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2717
    LANGUAGE sql IMMUTABLE
2718
    AS $_$
2719
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2720
util.qual_name((unnest).type), ', '), '')
2721
FROM unnest($1)
2722
$_$;
2723

    
2724

    
2725
--
2726
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2727
--
2728

    
2729
CREATE FUNCTION name(table_ regclass) RETURNS text
2730
    LANGUAGE sql STABLE
2731
    AS $_$
2732
SELECT relname::text FROM pg_class WHERE oid = $1
2733
$_$;
2734

    
2735

    
2736
--
2737
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2738
--
2739

    
2740
CREATE FUNCTION name(type regtype) RETURNS text
2741
    LANGUAGE sql STABLE
2742
    AS $_$
2743
SELECT typname::text FROM pg_type WHERE oid = $1
2744
$_$;
2745

    
2746

    
2747
--
2748
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2749
--
2750

    
2751
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2752
    LANGUAGE sql IMMUTABLE
2753
    AS $_$
2754
SELECT octet_length($1) >= util.namedatalen() - $2
2755
$_$;
2756

    
2757

    
2758
--
2759
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2760
--
2761

    
2762
CREATE FUNCTION namedatalen() RETURNS integer
2763
    LANGUAGE sql IMMUTABLE
2764
    AS $$
2765
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2766
$$;
2767

    
2768

    
2769
--
2770
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772

    
2773
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2774
    LANGUAGE sql IMMUTABLE
2775
    AS $_$
2776
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2777
$_$;
2778

    
2779

    
2780
--
2781
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2782
--
2783

    
2784
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2785
    LANGUAGE sql IMMUTABLE
2786
    AS $_$
2787
SELECT $1 IS NOT NULL
2788
$_$;
2789

    
2790

    
2791
--
2792
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2793
--
2794

    
2795
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2796
    LANGUAGE sql IMMUTABLE
2797
    AS $_$
2798
SELECT util.hstore($1, NULL) || '*=>*'
2799
$_$;
2800

    
2801

    
2802
--
2803
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2804
--
2805

    
2806
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2807
for use with _map()
2808
';
2809

    
2810

    
2811
--
2812
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2813
--
2814

    
2815
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2816
    LANGUAGE sql IMMUTABLE
2817
    AS $_$
2818
SELECT $2 + COALESCE($1, 0)
2819
$_$;
2820

    
2821

    
2822
--
2823
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2824
--
2825

    
2826
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2827
    LANGUAGE sql STABLE
2828
    AS $_$
2829
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2830
$_$;
2831

    
2832

    
2833
--
2834
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2835
--
2836

    
2837
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2838
    LANGUAGE sql
2839
    AS $_$
2840
SELECT util.eval($$INSERT INTO $$||$1||$$
2841
$$||util.ltrim_nl($2));
2842
-- make sure the created table has the correct estimated row count
2843
SELECT util.analyze_($1);
2844
$_$;
2845

    
2846

    
2847
--
2848
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2849
--
2850

    
2851
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2852
    LANGUAGE sql IMMUTABLE
2853
    AS $_$
2854
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2855
$_$;
2856

    
2857

    
2858
--
2859
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2860
--
2861

    
2862
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2863
    LANGUAGE sql
2864
    AS $_$
2865
SELECT util.set_comment($1, concat($2, util.comment($1)))
2866
$_$;
2867

    
2868

    
2869
--
2870
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2871
--
2872

    
2873
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2874
comment: must start and end with a newline
2875
';
2876

    
2877

    
2878
--
2879
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2880
--
2881

    
2882
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2883
    LANGUAGE sql IMMUTABLE
2884
    AS $_$
2885
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2886
$_$;
2887

    
2888

    
2889
--
2890
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2891
--
2892

    
2893
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2894
    LANGUAGE sql STABLE
2895
    SET search_path TO pg_temp
2896
    AS $_$
2897
SELECT $1::text
2898
$_$;
2899

    
2900

    
2901
--
2902
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2903
--
2904

    
2905
CREATE FUNCTION qual_name(type regtype) RETURNS text
2906
    LANGUAGE sql STABLE
2907
    SET search_path TO pg_temp
2908
    AS $_$
2909
SELECT $1::text
2910
$_$;
2911

    
2912

    
2913
--
2914
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2915
--
2916

    
2917
COMMENT ON FUNCTION qual_name(type regtype) IS '
2918
a type''s schema-qualified name
2919
';
2920

    
2921

    
2922
--
2923
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2924
--
2925

    
2926
CREATE FUNCTION qual_name(type unknown) RETURNS text
2927
    LANGUAGE sql STABLE
2928
    AS $_$
2929
SELECT util.qual_name($1::text::regtype)
2930
$_$;
2931

    
2932

    
2933
--
2934
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2935
--
2936

    
2937
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2938
    LANGUAGE sql IMMUTABLE
2939
    AS $_$
2940
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2941
$_$;
2942

    
2943

    
2944
--
2945
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2946
--
2947

    
2948
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2949
    LANGUAGE sql IMMUTABLE
2950
    AS $_$
2951
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2952
$_$;
2953

    
2954

    
2955
--
2956
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2957
--
2958

    
2959
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2960
    LANGUAGE sql IMMUTABLE
2961
    AS $_$
2962
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2963
$_$;
2964

    
2965

    
2966
--
2967
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2968
--
2969

    
2970
CREATE FUNCTION raise(type text, msg text) RETURNS void
2971
    LANGUAGE sql IMMUTABLE
2972
    AS $_X$
2973
SELECT util.eval($$
2974
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2975
  RETURNS void AS
2976
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2977
$__BODY1$
2978
BEGIN
2979
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2980
END;
2981
$__BODY1$
2982
  LANGUAGE plpgsql IMMUTABLE
2983
  COST 100;
2984
$$, verbose_ := false);
2985

    
2986
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2987
$_X$;
2988

    
2989

    
2990
--
2991
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2992
--
2993

    
2994
COMMENT ON FUNCTION raise(type text, msg text) IS '
2995
type: a log level from
2996
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2997
or a condition name from
2998
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2999
';
3000

    
3001

    
3002
--
3003
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
3004
--
3005

    
3006
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3007
    LANGUAGE sql IMMUTABLE
3008
    AS $_$
3009
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3010
$_$;
3011

    
3012

    
3013
--
3014
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3015
--
3016

    
3017
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3018
    LANGUAGE plpgsql IMMUTABLE STRICT
3019
    AS $$
3020
BEGIN
3021
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3022
END;
3023
$$;
3024

    
3025

    
3026
--
3027
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3028
--
3029

    
3030
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3031
    LANGUAGE sql IMMUTABLE
3032
    AS $_$
3033
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3034
$_$;
3035

    
3036

    
3037
--
3038
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3039
--
3040

    
3041
CREATE FUNCTION regexp_quote(str text) RETURNS text
3042
    LANGUAGE sql IMMUTABLE
3043
    AS $_$
3044
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3045
$_$;
3046

    
3047

    
3048
--
3049
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
3050
--
3051

    
3052
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3053
    LANGUAGE sql IMMUTABLE
3054
    AS $_$
3055
SELECT (CASE WHEN right($1, 1) = ')'
3056
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3057
$_$;
3058

    
3059

    
3060
--
3061
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3062
--
3063

    
3064
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3065
    LANGUAGE sql STABLE
3066
    AS $_$
3067
SELECT util.relation_type(util.relation_type_char($1))
3068
$_$;
3069

    
3070

    
3071
--
3072
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3073
--
3074

    
3075
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3076
    LANGUAGE sql IMMUTABLE
3077
    AS $_$
3078
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3079
$_$;
3080

    
3081

    
3082
--
3083
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3084
--
3085

    
3086
CREATE FUNCTION relation_type(type regtype) RETURNS text
3087
    LANGUAGE sql IMMUTABLE
3088
    AS $$
3089
SELECT 'TYPE'::text
3090
$$;
3091

    
3092

    
3093
--
3094
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
3095
--
3096

    
3097
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3098
    LANGUAGE sql STABLE
3099
    AS $_$
3100
SELECT relkind FROM pg_class WHERE oid = $1
3101
$_$;
3102

    
3103

    
3104
--
3105
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
3106
--
3107

    
3108
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3109
    LANGUAGE sql
3110
    AS $_$
3111
/* can't have in_table/out_table inherit from *each other*, because inheritance
3112
also causes the rows of the parent table to be included in the child table.
3113
instead, they need to inherit from a common, empty table. */
3114
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3115
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3116
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3117
SELECT util.inherit($2, $4);
3118
SELECT util.inherit($3, $4);
3119

    
3120
SELECT util.rematerialize_query($1, $$
3121
SELECT * FROM util.diff(
3122
  $$||util.quote_typed($2)||$$
3123
, $$||util.quote_typed($3)||$$
3124
, NULL::$$||$4||$$)
3125
$$);
3126

    
3127
/* the table unfortunately cannot be *materialized* in human-readable form,
3128
because this would create column name collisions between the two sides */
3129
SELECT util.prepend_comment($1, '
3130
to view this table in human-readable form (with each side''s tuple column
3131
expanded to its component fields):
3132
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3133

    
3134
to display NULL values that are extra or missing:
3135
SELECT * FROM '||$1||';
3136
');
3137
$_$;
3138

    
3139

    
3140
--
3141
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3142
--
3143

    
3144
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3145
type_table (*required*): table to create as the shared base type
3146
';
3147

    
3148

    
3149
--
3150
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3151
--
3152

    
3153
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3154
    LANGUAGE sql
3155
    AS $_$
3156
SELECT util.drop_table($1);
3157
SELECT util.materialize_query($1, $2);
3158
$_$;
3159

    
3160

    
3161
--
3162
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3163
--
3164

    
3165
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3166
idempotent, but repeats action each time
3167
';
3168

    
3169

    
3170
--
3171
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3172
--
3173

    
3174
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3175
    LANGUAGE sql
3176
    AS $_$
3177
SELECT util.drop_table($1);
3178
SELECT util.materialize_view($1, $2);
3179
$_$;
3180

    
3181

    
3182
--
3183
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3184
--
3185

    
3186
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3187
idempotent, but repeats action each time
3188
';
3189

    
3190

    
3191
--
3192
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3193
--
3194

    
3195
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3196
    LANGUAGE sql
3197
    AS $_$
3198
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3199
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3200
FROM util.col_names($1::text::regtype) f (name);
3201
SELECT NULL::void; -- don't fold away functions called in previous query
3202
$_$;
3203

    
3204

    
3205
--
3206
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3207
--
3208

    
3209
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3210
idempotent
3211
';
3212

    
3213

    
3214
--
3215
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3216
--
3217

    
3218
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3219
    LANGUAGE sql
3220
    AS $_$
3221
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3222
included in the debug SQL */
3223
SELECT util.rename_relation(util.qual_name($1), $2)
3224
$_$;
3225

    
3226

    
3227
--
3228
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3229
--
3230

    
3231
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3232
    LANGUAGE sql
3233
    AS $_$
3234
/* 'ALTER TABLE can be used with views too'
3235
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3236
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3237
||quote_ident($2))
3238
$_$;
3239

    
3240

    
3241
--
3242
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3243
--
3244

    
3245
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3246
idempotent
3247
';
3248

    
3249

    
3250
--
3251
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3252
--
3253

    
3254
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3255
    LANGUAGE sql IMMUTABLE
3256
    AS $_$
3257
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3258
$_$;
3259

    
3260

    
3261
--
3262
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3263
--
3264

    
3265
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3266
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 
3267
';
3268

    
3269

    
3270
--
3271
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3272
--
3273

    
3274
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3275
    LANGUAGE sql
3276
    AS $_$
3277
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3278
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3279
SELECT util.set_col_names($1, $2);
3280
$_$;
3281

    
3282

    
3283
--
3284
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3285
--
3286

    
3287
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3288
idempotent.
3289
alters the names table, so it will need to be repopulated after running this function.
3290
';
3291

    
3292

    
3293
--
3294
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3295
--
3296

    
3297
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3298
    LANGUAGE sql
3299
    AS $_$
3300
SELECT util.drop_table($1);
3301
SELECT util.mk_map_table($1);
3302
$_$;
3303

    
3304

    
3305
--
3306
-- Name: restore_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3307
--
3308

    
3309
CREATE FUNCTION restore_views(views text[]) RETURNS void
3310
    LANGUAGE sql
3311
    AS $_$
3312
SELECT util.debug_print_var('views', $1);
3313
SELECT util.create_if_not_exists(recreate_cmd)
3314
FROM unnest($1) recreate_cmd; -- in forward dependency order
3315
	/* create_if_not_exists() rather than eval(), because cmd might manually
3316
	re-create a deleted dependent view, causing it to already exist */
3317
SELECT NULL::void; -- don't fold away functions called in previous query
3318
$_$;
3319

    
3320

    
3321
--
3322
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3323
--
3324

    
3325
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3326
    LANGUAGE sql
3327
    AS $_$
3328
SELECT util.drop_column($1, $2, force := true)
3329
$_$;
3330

    
3331

    
3332
--
3333
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3334
--
3335

    
3336
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3337
    LANGUAGE sql IMMUTABLE
3338
    AS $_$
3339
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3340
$_$;
3341

    
3342

    
3343
--
3344
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3345
--
3346

    
3347
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3348
    LANGUAGE sql IMMUTABLE
3349
    AS $_$
3350
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3351
ELSE util.mk_set_search_path(for_printing := true)||$$;
3352
$$ END)||$1
3353
$_$;
3354

    
3355

    
3356
--
3357
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3358
--
3359

    
3360
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3361
    LANGUAGE plpgsql STRICT
3362
    AS $$
3363
DECLARE
3364
	result text = NULL;
3365
BEGIN
3366
	BEGIN
3367
		result = util.show_create_view(view_, replace := false);
3368
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3369
			(eg. invalid_table_definition), instead of the standard
3370
			duplicate_table exception caught by util.create_if_not_exists() */
3371
		PERFORM util.drop_view(view_);
3372
	EXCEPTION
3373
		WHEN undefined_table THEN NULL;
3374
	END;
3375
	RETURN result;
3376
END;
3377
$$;
3378

    
3379

    
3380
--
3381
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3382
--
3383

    
3384
CREATE FUNCTION save_drop_views(views text[]) RETURNS text[]
3385
    LANGUAGE sql
3386
    AS $_$
3387
SELECT /*return in forward dependency order*/util.array_reverse(array(
3388
SELECT util.save_drop_view(view_)
3389
FROM unnest(/*drop in reverse dependency order*/util.array_reverse($1)) view_
3390
))
3391
$_$;
3392

    
3393

    
3394
--
3395
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3396
--
3397

    
3398
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3399
    LANGUAGE sql STABLE
3400
    AS $_$
3401
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3402
$_$;
3403

    
3404

    
3405
--
3406
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3407
--
3408

    
3409
CREATE FUNCTION schema(table_ regclass) RETURNS text
3410
    LANGUAGE sql STABLE
3411
    AS $_$
3412
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3413
$_$;
3414

    
3415

    
3416
--
3417
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3418
--
3419

    
3420
CREATE FUNCTION schema(type regtype) RETURNS text
3421
    LANGUAGE sql STABLE
3422
    AS $_$
3423
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3424
$_$;
3425

    
3426

    
3427
--
3428
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3429
--
3430

    
3431
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3432
    LANGUAGE sql STABLE
3433
    AS $_$
3434
SELECT util.schema(pg_typeof($1))
3435
$_$;
3436

    
3437

    
3438
--
3439
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3440
--
3441

    
3442
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3443
    LANGUAGE sql STABLE
3444
    AS $_$
3445
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3446
$_$;
3447

    
3448

    
3449
--
3450
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3451
--
3452

    
3453
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3454
a schema bundle is a group of schemas with a common prefix
3455
';
3456

    
3457

    
3458
--
3459
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3460
--
3461

    
3462
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3463
    LANGUAGE sql
3464
    AS $_$
3465
SELECT util.schema_rename(old_schema,
3466
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3467
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3468
SELECT NULL::void; -- don't fold away functions called in previous query
3469
$_$;
3470

    
3471

    
3472
--
3473
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3474
--
3475

    
3476
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3477
    LANGUAGE plpgsql
3478
    AS $$
3479
BEGIN
3480
	-- don't schema_bundle_rm() the schema_bundle to keep!
3481
	IF replace = with_ THEN RETURN; END IF;
3482
	
3483
	PERFORM util.schema_bundle_rm(replace);
3484
	PERFORM util.schema_bundle_rename(with_, replace);
3485
END;
3486
$$;
3487

    
3488

    
3489
--
3490
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3491
--
3492

    
3493
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3494
    LANGUAGE sql
3495
    AS $_$
3496
SELECT util.schema_rm(schema)
3497
FROM util.schema_bundle_get_schemas($1) f (schema);
3498
SELECT NULL::void; -- don't fold away functions called in previous query
3499
$_$;
3500

    
3501

    
3502
--
3503
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3504
--
3505

    
3506
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3507
    LANGUAGE sql STABLE
3508
    AS $_$
3509
SELECT quote_ident(util.schema($1))
3510
$_$;
3511

    
3512

    
3513
--
3514
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3515
--
3516

    
3517
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3518
    LANGUAGE sql IMMUTABLE
3519
    AS $_$
3520
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3521
$_$;
3522

    
3523

    
3524
--
3525
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3526
--
3527

    
3528
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3529
    LANGUAGE sql STABLE
3530
    AS $_$
3531
SELECT oid FROM pg_namespace WHERE nspname = $1
3532
$_$;
3533

    
3534

    
3535
--
3536
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3537
--
3538

    
3539
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3540
    LANGUAGE sql IMMUTABLE
3541
    AS $_$
3542
SELECT util.schema_regexp(schema_anchor := $1)
3543
$_$;
3544

    
3545

    
3546
--
3547
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3548
--
3549

    
3550
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3551
    LANGUAGE sql IMMUTABLE
3552
    AS $_$
3553
SELECT util.str_equality_regexp(util.schema($1))
3554
$_$;
3555

    
3556

    
3557
--
3558
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3559
--
3560

    
3561
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3562
    LANGUAGE sql
3563
    AS $_$
3564
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3565
$_$;
3566

    
3567

    
3568
--
3569
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3570
--
3571

    
3572
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3573
    LANGUAGE plpgsql
3574
    AS $$
3575
BEGIN
3576
	-- don't schema_rm() the schema to keep!
3577
	IF replace = with_ THEN RETURN; END IF;
3578
	
3579
	PERFORM util.schema_rm(replace);
3580
	PERFORM util.schema_rename(with_, replace);
3581
END;
3582
$$;
3583

    
3584

    
3585
--
3586
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3587
--
3588

    
3589
CREATE FUNCTION schema_rm(schema text) RETURNS void
3590
    LANGUAGE sql
3591
    AS $_$
3592
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3593
$_$;
3594

    
3595

    
3596
--
3597
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3598
--
3599

    
3600
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3601
    LANGUAGE sql
3602
    AS $_$
3603
SELECT util.eval(
3604
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3605
$_$;
3606

    
3607

    
3608
--
3609
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3610
--
3611

    
3612
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3613
    LANGUAGE plpgsql STRICT
3614
    AS $_$
3615
DECLARE
3616
    old text[] = ARRAY(SELECT util.col_names(table_));
3617
    new text[] = ARRAY(SELECT util.map_values(names));
3618
BEGIN
3619
    old = old[1:array_length(new, 1)]; -- truncate to same length
3620
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3621
||$$ TO $$||quote_ident(value))
3622
    FROM each(hstore(old, new))
3623
    WHERE value != key -- not same name
3624
    ;
3625
END;
3626
$_$;
3627

    
3628

    
3629
--
3630
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3631
--
3632

    
3633
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3634
idempotent
3635
';
3636

    
3637

    
3638
--
3639
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3640
--
3641

    
3642
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3643
    LANGUAGE plpgsql STRICT
3644
    AS $_$
3645
DECLARE
3646
	row_ util.map;
3647
BEGIN
3648
	-- rename any metadata cols rather than re-adding them with new names
3649
	BEGIN
3650
		PERFORM util.set_col_names(table_, names);
3651
	EXCEPTION
3652
		WHEN array_subscript_error THEN -- selective suppress
3653
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3654
				-- metadata cols not yet added
3655
			ELSE RAISE;
3656
			END IF;
3657
	END;
3658
	
3659
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3660
	LOOP
3661
		PERFORM util.mk_const_col((table_, row_."to"),
3662
			substring(row_."from" from 2));
3663
	END LOOP;
3664
	
3665
	PERFORM util.set_col_names(table_, names);
3666
END;
3667
$_$;
3668

    
3669

    
3670
--
3671
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3672
--
3673

    
3674
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3675
idempotent.
3676
the metadata mappings must be *last* in the names table.
3677
';
3678

    
3679

    
3680
--
3681
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3682
--
3683

    
3684
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3685
    LANGUAGE sql
3686
    AS $_$
3687
SELECT util.eval(COALESCE(
3688
$$ALTER TABLE $$||$1||$$
3689
$$||(
3690
	SELECT
3691
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3692
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
3693
, $$)
3694
	FROM
3695
	(
3696
		SELECT
3697
		  quote_ident(col_name) AS col_name_sql
3698
		, util.col_type(($1, col_name)) AS curr_type
3699
		, type AS target_type
3700
		FROM unnest($2)
3701
	) s
3702
	WHERE curr_type != target_type
3703
), ''))
3704
$_$;
3705

    
3706

    
3707
--
3708
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3709
--
3710

    
3711
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3712
idempotent
3713
';
3714

    
3715

    
3716
--
3717
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3718
--
3719

    
3720
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3721
    LANGUAGE sql
3722
    AS $_$
3723
SELECT util.eval(util.mk_set_comment($1, $2))
3724
$_$;
3725

    
3726

    
3727
--
3728
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3729
--
3730

    
3731
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3732
    LANGUAGE sql
3733
    AS $_$
3734
SELECT util.eval(util.mk_set_search_path($1, $2))
3735
$_$;
3736

    
3737

    
3738
--
3739
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3740
--
3741

    
3742
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
3743
    LANGUAGE sql STABLE
3744
    AS $_$
3745
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
3746
||$1||$$ AS
3747
$$||pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
3748
$$||util.show_grants_for($1)
3749
||util.show_set_comment($1)||$$
3750
$$
3751
$_$;
3752

    
3753

    
3754
--
3755
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3756
--
3757

    
3758
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3759
    LANGUAGE sql STABLE
3760
    AS $_$
3761
SELECT string_agg(cmd, '')
3762
FROM
3763
(
3764
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3765
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3766
$$ ELSE '' END) AS cmd
3767
	FROM util.grants_users() f (user_)
3768
) s
3769
$_$;
3770

    
3771

    
3772
--
3773
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3774
--
3775

    
3776
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['c'::text, 'r'::text, 'v'::text]) RETURNS SETOF regclass
3777
    LANGUAGE sql STABLE
3778
    AS $_$
3779
SELECT oid FROM pg_class
3780
WHERE relkind = ANY($3) AND relname ~ $1
3781
AND util.schema_matches(util.schema(relnamespace), $2)
3782
ORDER BY relname
3783
$_$;
3784

    
3785

    
3786
--
3787
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
3788
--
3789

    
3790
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
3791
    LANGUAGE sql STABLE
3792
    AS $_$
3793
SELECT util.mk_set_comment($1, util.comment($1))
3794
$_$;
3795

    
3796

    
3797
--
3798
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3799
--
3800

    
3801
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3802
    LANGUAGE sql STABLE
3803
    AS $_$
3804
SELECT oid
3805
FROM pg_type
3806
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3807
ORDER BY typname
3808
$_$;
3809

    
3810

    
3811
--
3812
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3813
--
3814

    
3815
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3816
    LANGUAGE sql STABLE
3817
    AS $_$
3818
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3819
$_$;
3820

    
3821

    
3822
--
3823
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3824
--
3825

    
3826
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3827
    LANGUAGE sql IMMUTABLE
3828
    AS $_$
3829
SELECT '^'||util.regexp_quote($1)||'$'
3830
$_$;
3831

    
3832

    
3833
--
3834
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3835
--
3836

    
3837
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3838
    LANGUAGE plpgsql STABLE STRICT
3839
    AS $_$
3840
DECLARE
3841
    hstore hstore;
3842
BEGIN
3843
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3844
        table_||$$))$$ INTO STRICT hstore;
3845
    RETURN hstore;
3846
END;
3847
$_$;
3848

    
3849

    
3850
--
3851
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3852
--
3853

    
3854
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3855
    LANGUAGE sql STABLE
3856
    AS $_$
3857
SELECT COUNT(*) > 0 FROM pg_constraint
3858
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3859
$_$;
3860

    
3861

    
3862
--
3863
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3864
--
3865

    
3866
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3867
gets whether a status flag is set by the presence of a table constraint
3868
';
3869

    
3870

    
3871
--
3872
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3873
--
3874

    
3875
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3876
    LANGUAGE sql
3877
    AS $_$
3878
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3879
||quote_ident($2)||$$ CHECK (true)$$)
3880
$_$;
3881

    
3882

    
3883
--
3884
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3885
--
3886

    
3887
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3888
stores a status flag by the presence of a table constraint.
3889
idempotent.
3890
';
3891

    
3892

    
3893
--
3894
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3895
--
3896

    
3897
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3898
    LANGUAGE sql STABLE
3899
    AS $_$
3900
SELECT util.table_flag__get($1, 'nulls_mapped')
3901
$_$;
3902

    
3903

    
3904
--
3905
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3906
--
3907

    
3908
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3909
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3910
';
3911

    
3912

    
3913
--
3914
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3915
--
3916

    
3917
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3918
    LANGUAGE sql
3919
    AS $_$
3920
SELECT util.table_flag__set($1, 'nulls_mapped')
3921
$_$;
3922

    
3923

    
3924
--
3925
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3926
--
3927

    
3928
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3929
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3930
idempotent.
3931
';
3932

    
3933

    
3934
--
3935
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3936
--
3937

    
3938
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3939
    LANGUAGE sql
3940
    AS $_$
3941
-- save data before truncating main table
3942
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3943

    
3944
-- repopulate main table w/ copies column
3945
SELECT util.truncate($1);
3946
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3947
SELECT util.populate_table($1, $$
3948
SELECT (table_).*, copies
3949
FROM (
3950
	SELECT table_, COUNT(*) AS copies
3951
	FROM pg_temp.__copy table_
3952
	GROUP BY table_
3953
) s
3954
$$);
3955

    
3956
-- delete temp table so it doesn't stay around until end of connection
3957
SELECT util.drop_table('pg_temp.__copy');
3958
$_$;
3959

    
3960

    
3961
--
3962
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3963
--
3964

    
3965
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3966
    LANGUAGE plpgsql STRICT
3967
    AS $_$
3968
DECLARE
3969
    row record;
3970
BEGIN
3971
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3972
    LOOP
3973
        IF row.global_name != row.name THEN
3974
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3975
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3976
        END IF;
3977
    END LOOP;
3978
END;
3979
$_$;
3980

    
3981

    
3982
--
3983
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3984
--
3985

    
3986
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3987
idempotent
3988
';
3989

    
3990

    
3991
--
3992
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3993
--
3994

    
3995
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
3996
    LANGUAGE sql
3997
    AS $_$
3998
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
3999
SELECT NULL::void; -- don't fold away functions called in previous query
4000
$_$;
4001

    
4002

    
4003
--
4004
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
4005
--
4006

    
4007
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass, force boolean) IS '
4008
trims table_ to include only columns in the original data
4009

    
4010
by default, cascadingly drops dependent columns so that they don''t prevent
4011
trim() from succeeding. note that this requires the dependent columns to then be
4012
manually re-created.
4013

    
4014
idempotent
4015
';
4016

    
4017

    
4018
--
4019
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4020
--
4021

    
4022
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4023
    LANGUAGE plpgsql STRICT
4024
    AS $_$
4025
BEGIN
4026
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4027
END;
4028
$_$;
4029

    
4030

    
4031
--
4032
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4033
--
4034

    
4035
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4036
idempotent
4037
';
4038

    
4039

    
4040
--
4041
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4042
--
4043

    
4044
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4045
    LANGUAGE sql IMMUTABLE
4046
    AS $_$
4047
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4048
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4049
$_$;
4050

    
4051

    
4052
--
4053
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4054
--
4055

    
4056
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4057
    LANGUAGE plpgsql IMMUTABLE
4058
    AS $$
4059
BEGIN
4060
	/* need explicit cast because some types not implicitly-castable, and also
4061
	to make the cast happen inside the try block. (*implicit* casts to the
4062
	return type happen at the end of the function, outside any block.) */
4063
	RETURN util.cast(value, ret_type_null);
4064
EXCEPTION
4065
WHEN data_exception THEN
4066
	PERFORM util.raise('WARNING', SQLERRM);
4067
	RETURN NULL;
4068
END;
4069
$$;
4070

    
4071

    
4072
--
4073
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4074
--
4075

    
4076
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4077
ret_type_null: NULL::ret_type
4078
';
4079

    
4080

    
4081
--
4082
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4083
--
4084

    
4085
CREATE FUNCTION try_create(sql text) RETURNS void
4086
    LANGUAGE plpgsql STRICT
4087
    AS $$
4088
BEGIN
4089
	PERFORM util.eval(sql);
4090
EXCEPTION
4091
WHEN   not_null_violation
4092
		/* trying to add NOT NULL column to parent table, which cascades to
4093
		child table whose values for the new column will be NULL */
4094
	OR wrong_object_type -- trying to alter a view's columns
4095
	OR undefined_column
4096
	OR duplicate_column
4097
THEN NULL;
4098
WHEN datatype_mismatch THEN
4099
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4100
	ELSE RAISE; -- rethrow
4101
	END IF;
4102
END;
4103
$$;
4104

    
4105

    
4106
--
4107
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4108
--
4109

    
4110
COMMENT ON FUNCTION try_create(sql text) IS '
4111
idempotent
4112
';
4113

    
4114

    
4115
--
4116
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4117
--
4118

    
4119
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4120
    LANGUAGE sql
4121
    AS $_$
4122
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4123
$_$;
4124

    
4125

    
4126
--
4127
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4128
--
4129

    
4130
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4131
idempotent
4132
';
4133

    
4134

    
4135
--
4136
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4137
--
4138

    
4139
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4140
    LANGUAGE sql IMMUTABLE
4141
    AS $_$
4142
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4143
$_$;
4144

    
4145

    
4146
--
4147
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4148
--
4149

    
4150
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4151
a type''s NOT NULL qualifier
4152
';
4153

    
4154

    
4155
--
4156
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4157
--
4158

    
4159
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4160
    LANGUAGE sql STABLE
4161
    AS $_$
4162
SELECT (attname::text, atttypid)::util.col_cast
4163
FROM pg_attribute
4164
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4165
ORDER BY attnum
4166
$_$;
4167

    
4168

    
4169
--
4170
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4171
--
4172

    
4173
CREATE FUNCTION typeof(value anyelement) RETURNS text
4174
    LANGUAGE sql IMMUTABLE
4175
    AS $_$
4176
SELECT util.qual_name(pg_typeof($1))
4177
$_$;
4178

    
4179

    
4180
--
4181
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4182
--
4183

    
4184
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4185
    LANGUAGE plpgsql STABLE
4186
    AS $_$
4187
DECLARE
4188
    type regtype;
4189
BEGIN
4190
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4191
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4192
    RETURN type;
4193
END;
4194
$_$;
4195

    
4196

    
4197
--
4198
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4199
--
4200

    
4201
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4202
    LANGUAGE sql
4203
    AS $_$
4204
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4205
$_$;
4206

    
4207

    
4208
--
4209
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4210
--
4211

    
4212
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4213
auto-appends util to the search_path to enable use of util operators
4214
';
4215

    
4216

    
4217
--
4218
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4219
--
4220

    
4221
CREATE AGGREGATE all_same(anyelement) (
4222
    SFUNC = all_same_transform,
4223
    STYPE = anyarray,
4224
    FINALFUNC = all_same_final
4225
);
4226

    
4227

    
4228
--
4229
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4230
--
4231

    
4232
COMMENT ON AGGREGATE all_same(anyelement) IS '
4233
includes NULLs in comparison
4234
';
4235

    
4236

    
4237
--
4238
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4239
--
4240

    
4241
CREATE AGGREGATE join_strs(text, text) (
4242
    SFUNC = join_strs_transform,
4243
    STYPE = text
4244
);
4245

    
4246

    
4247
--
4248
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4249
--
4250

    
4251
CREATE OPERATOR %== (
4252
    PROCEDURE = "%==",
4253
    LEFTARG = anyelement,
4254
    RIGHTARG = anyelement
4255
);
4256

    
4257

    
4258
--
4259
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4260
--
4261

    
4262
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4263
returns whether the map-keys of the compared values are the same
4264
(mnemonic: % is the Perl symbol for a hash map)
4265

    
4266
should be overridden for types that store both keys and values
4267

    
4268
used in a FULL JOIN to select which columns to join on
4269
';
4270

    
4271

    
4272
--
4273
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4274
--
4275

    
4276
CREATE OPERATOR -> (
4277
    PROCEDURE = map_get,
4278
    LEFTARG = regclass,
4279
    RIGHTARG = text
4280
);
4281

    
4282

    
4283
--
4284
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4285
--
4286

    
4287
CREATE OPERATOR => (
4288
    PROCEDURE = hstore,
4289
    LEFTARG = text[],
4290
    RIGHTARG = text
4291
);
4292

    
4293

    
4294
--
4295
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4296
--
4297

    
4298
COMMENT ON OPERATOR => (text[], text) IS '
4299
usage: array[''key1'', ...]::text[] => ''value''
4300
';
4301

    
4302

    
4303
--
4304
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4305
--
4306

    
4307
CREATE OPERATOR ?*>= (
4308
    PROCEDURE = is_populated_more_often_than,
4309
    LEFTARG = anyelement,
4310
    RIGHTARG = anyelement
4311
);
4312

    
4313

    
4314
--
4315
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4316
--
4317

    
4318
CREATE OPERATOR ?>= (
4319
    PROCEDURE = is_more_complete_than,
4320
    LEFTARG = anyelement,
4321
    RIGHTARG = anyelement
4322
);
4323

    
4324

    
4325
--
4326
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4327
--
4328

    
4329
CREATE OPERATOR ||% (
4330
    PROCEDURE = concat_esc,
4331
    LEFTARG = text,
4332
    RIGHTARG = text
4333
);
4334

    
4335

    
4336
--
4337
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4338
--
4339

    
4340
COMMENT ON OPERATOR ||% (text, text) IS '
4341
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4342
';
4343

    
4344

    
4345
--
4346
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4347
--
4348

    
4349
CREATE TABLE map (
4350
    "from" text NOT NULL,
4351
    "to" text,
4352
    filter text,
4353
    notes text
4354
);
4355

    
4356

    
4357
--
4358
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4359
--
4360

    
4361

    
4362

    
4363
--
4364
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4365
--
4366

    
4367

    
4368

    
4369
--
4370
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4371
--
4372

    
4373
ALTER TABLE ONLY map
4374
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4375

    
4376

    
4377
--
4378
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4379
--
4380

    
4381
ALTER TABLE ONLY map
4382
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4383

    
4384

    
4385
--
4386
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4387
--
4388

    
4389
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4390

    
4391

    
4392
--
4393
-- PostgreSQL database dump complete
4394
--
4395

    
(21-21/31)