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: db_item; Type: TYPE; Schema: util; Owner: -
76
--
77

    
78
CREATE TYPE db_item AS (
79
	path text,
80
	def text
81
);
82

    
83

    
84
--
85
-- Name: restore_views_info; Type: TYPE; Schema: util; Owner: -
86
--
87

    
88
CREATE TYPE restore_views_info AS (
89
	views db_item[]
90
);
91

    
92

    
93
--
94
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
95
--
96

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

    
103

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

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

    
123

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

    
128
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
129
_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.
130
';
131

    
132

    
133
--
134
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
135
--
136

    
137
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
138
    LANGUAGE sql IMMUTABLE
139
    AS $_$
140
SELECT avg(value)
141
FROM
142
(VALUES
143
      ($1)
144
    , ($2)
145
    , ($3)
146
    , ($4)
147
    , ($5)
148
)
149
AS v (value)
150
$_$;
151

    
152

    
153
--
154
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
155
--
156

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

    
171

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

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

    
189

    
190
--
191
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
192
--
193

    
194
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
195
    LANGUAGE sql IMMUTABLE
196
    AS $_$
197
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
198
$_$;
199

    
200

    
201
--
202
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
203
--
204

    
205
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
206
    LANGUAGE sql IMMUTABLE
207
    AS $_$
208
SELECT $1 = $2
209
$_$;
210

    
211

    
212
--
213
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
214
--
215

    
216
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
217
    LANGUAGE sql IMMUTABLE
218
    AS $_$
219
-- Fix dates after threshold date
220
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
221
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
222
$_$;
223

    
224

    
225
--
226
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
227
--
228

    
229
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
230
    LANGUAGE sql IMMUTABLE
231
    AS $_$
232
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
233
$_$;
234

    
235

    
236
--
237
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
238
--
239

    
240
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
241
    LANGUAGE sql IMMUTABLE
242
    AS $_$
243
SELECT util._if($1 != '', $2, $3)
244
$_$;
245

    
246

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

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

    
257

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

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

    
268

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

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

    
279

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

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

    
290

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

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

    
301

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

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

    
316

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

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

    
341

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

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

    
352

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

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

    
391

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

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

    
402

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

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

    
441

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

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

    
452

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

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

    
463

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

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

    
474

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

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

    
485

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

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

    
511

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

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

    
531

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

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

    
540

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

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

    
551

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

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

    
562

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

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

    
580

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

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

    
589

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

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

    
600

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

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

    
617

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

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

    
628

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

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

    
639

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

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

    
648

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

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

    
659

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

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

    
670

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

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

    
681

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

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

    
690

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

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

    
701

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

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

    
715

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

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

    
731

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

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

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

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

    
746
ret_type_null: NULL::ret_type
747
';
748

    
749

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

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

    
760

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

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

    
776

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

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

    
785

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

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

    
799

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

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

    
810

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

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

    
826

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

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

    
850

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

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

    
873

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

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

    
884

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

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

    
893

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

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

    
909

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

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

    
926

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

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

    
940

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

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

    
953

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

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

    
976

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

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

    
987

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

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

    
998

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

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

    
1009

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

    
1014
CREATE FUNCTION copy(from_ regclass, to_ text) RETURNS void
1015
    LANGUAGE sql
1016
    AS $_$
1017
SELECT util.copy_struct($1, $2);
1018
SELECT util.copy_data($1, $2);
1019
$_$;
1020

    
1021

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

    
1026
CREATE FUNCTION copy_data(from_ regclass, to_ regclass) RETURNS void
1027
    LANGUAGE sql
1028
    AS $_$
1029
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT * FROM $$||$1)
1030
$_$;
1031

    
1032

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

    
1037
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1038
    LANGUAGE sql
1039
    AS $_$
1040
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1041
$_$;
1042

    
1043

    
1044
--
1045
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1046
--
1047

    
1048
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1049
    LANGUAGE sql
1050
    AS $_$
1051
SELECT util.materialize_view($2, $1)
1052
$_$;
1053

    
1054

    
1055
--
1056
-- Name: create_if_not_exists(text, text); Type: FUNCTION; Schema: util; Owner: -
1057
--
1058

    
1059
CREATE FUNCTION create_if_not_exists(sql text, relation text DEFAULT NULL::text) RETURNS void
1060
    LANGUAGE plpgsql
1061
    AS $$
1062
BEGIN
1063
	/* always generate standard exception if exists, even if table definition
1064
	would be invalid (which generates a variety of exceptions) */
1065
	IF util.relation_exists(relation) THEN
1066
		PERFORM util.raise('NOTICE', relation||' already exists, skipping');
1067
		RAISE duplicate_table;
1068
	END IF;
1069
	PERFORM util.eval(sql);
1070
EXCEPTION
1071
WHEN   duplicate_table
1072
	OR duplicate_object -- eg. constraint
1073
	OR duplicate_column
1074
	OR duplicate_function
1075
THEN NULL;
1076
WHEN invalid_table_definition THEN
1077
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1078
	ELSE RAISE;
1079
	END IF;
1080
END;
1081
$$;
1082

    
1083

    
1084
--
1085
-- Name: FUNCTION create_if_not_exists(sql text, relation text); Type: COMMENT; Schema: util; Owner: -
1086
--
1087

    
1088
COMMENT ON FUNCTION create_if_not_exists(sql text, relation text) IS '
1089
idempotent
1090
';
1091

    
1092

    
1093
--
1094
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1095
--
1096

    
1097
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1098
    LANGUAGE sql STABLE
1099
    AS $$
1100
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1101
$$;
1102

    
1103

    
1104
--
1105
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1106
--
1107

    
1108
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1109
    LANGUAGE sql IMMUTABLE
1110
    AS $_$
1111
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1112
$_$;
1113

    
1114

    
1115
--
1116
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1117
--
1118

    
1119
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1120
    LANGUAGE sql IMMUTABLE
1121
    AS $_$
1122
SELECT util.debug_print_value('returns: ', $1, $2);
1123
SELECT $1;
1124
$_$;
1125

    
1126

    
1127
--
1128
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1129
--
1130

    
1131
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1132
    LANGUAGE sql IMMUTABLE
1133
    AS $_$
1134
/* newline before so the query starts at the beginning of the line.
1135
newline after to visually separate queries from one another. */
1136
SELECT util.raise('NOTICE', $$
1137
$$||util.runnable_sql($1)||$$
1138
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1139
$_$;
1140

    
1141

    
1142
--
1143
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1144
--
1145

    
1146
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1147
    LANGUAGE sql IMMUTABLE
1148
    AS $_$
1149
SELECT util.raise('NOTICE', concat($1,
1150
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1151
$$)
1152
$_$;
1153

    
1154

    
1155
--
1156
-- Name: debug_print_var(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1157
--
1158

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

    
1168

    
1169
--
1170
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1171
--
1172

    
1173
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1174
    LANGUAGE sql STABLE
1175
    AS $_$
1176
SELECT util.eval2set($$
1177
SELECT col
1178
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1179
LEFT JOIN $$||$2||$$ ON "to" = col
1180
WHERE "from" IS NULL
1181
$$, NULL::text)
1182
$_$;
1183

    
1184

    
1185
--
1186
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1187
--
1188

    
1189
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1190
gets table_''s derived columns (all the columns not in the names table)
1191
';
1192

    
1193

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

    
1198
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1199
    LANGUAGE sql
1200
    AS $_$
1201
-- create a diff when the # of copies of a row differs between the tables
1202
SELECT util.to_freq($1);
1203
SELECT util.to_freq($2);
1204
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1205

    
1206
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1207
$_$;
1208

    
1209

    
1210
--
1211
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1212
--
1213

    
1214
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1215
usage:
1216
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1217

    
1218
col_type_null (*required*): NULL::shared_base_type
1219
';
1220

    
1221

    
1222
--
1223
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1224
--
1225

    
1226
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
1227
    LANGUAGE plpgsql
1228
    SET search_path TO pg_temp
1229
    AS $_$
1230
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1231
changes of search_path (schema elements are bound at inline time rather than
1232
runtime) */
1233
/* function option search_path is needed to limit the effects of
1234
`SET LOCAL search_path` to the current function */
1235
BEGIN
1236
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1237
	
1238
	PERFORM util.mk_keys_func(pg_typeof($3));
1239
	RETURN QUERY
1240
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1241
$$/* need to explicitly cast each side to the return type because this does not
1242
happen automatically even when an implicit cast is available */
1243
  left_::$$||util.typeof($3)||$$
1244
, right_::$$||util.typeof($3)
1245
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1246
the *same* base type, *even though* this is optional when using a custom %== */
1247
, util._if($4, $$true/*= CROSS JOIN*/$$,
1248
$$ left_::$$||util.typeof($3)||$$
1249
%== right_::$$||util.typeof($3)||$$
1250
	-- refer to EXPLAIN output for expansion of %==$$
1251
)
1252
,     $$         left_::$$||util.typeof($3)||$$
1253
IS DISTINCT FROM right_::$$||util.typeof($3)
1254
), $3)
1255
	;
1256
END;
1257
$_$;
1258

    
1259

    
1260
--
1261
-- 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: -
1262
--
1263

    
1264
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1265
col_type_null (*required*): NULL::col_type
1266
single_row: whether the tables consist of a single row, which should be
1267
	displayed side-by-side
1268

    
1269
to match up rows using a subset of the columns, create a custom keys() function
1270
which returns this subset as a record:
1271
-- note that OUT parameters for the returned fields are *not* needed
1272
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1273
  RETURNS record AS
1274
$BODY$
1275
SELECT ($1.key_field_0, $1.key_field_1)
1276
$BODY$
1277
  LANGUAGE sql IMMUTABLE
1278
  COST 100;
1279

    
1280

    
1281
to run EXPLAIN on the FULL JOIN query:
1282
# run this function
1283
# look for a NOTICE containing the expanded query that it ran
1284
# run EXPLAIN on this expanded query
1285
';
1286

    
1287

    
1288
--
1289
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1290
--
1291

    
1292
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
1293
    LANGUAGE sql
1294
    AS $_$
1295
SELECT * FROM util.diff($1::text, $2::text, $3,
1296
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1297
$_$;
1298

    
1299

    
1300
--
1301
-- 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: -
1302
--
1303

    
1304
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1305
helper function used by diff(regclass, regclass)
1306

    
1307
usage:
1308
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1309

    
1310
col_type_null (*required*): NULL::shared_base_type
1311
';
1312

    
1313

    
1314
--
1315
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1316
--
1317

    
1318
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1319
    LANGUAGE sql
1320
    AS $_$
1321
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1322
$_$;
1323

    
1324

    
1325
--
1326
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1327
--
1328

    
1329
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1330
idempotent
1331
';
1332

    
1333

    
1334
--
1335
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1336
--
1337

    
1338
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1339
    LANGUAGE sql
1340
    AS $_$
1341
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1342
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1343
$_$;
1344

    
1345

    
1346
--
1347
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1348
--
1349

    
1350
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1351
idempotent
1352
';
1353

    
1354

    
1355
--
1356
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1357
--
1358

    
1359
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1360
    LANGUAGE sql
1361
    AS $_$
1362
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1363
SELECT NULL::void; -- don't fold away functions called in previous query
1364
$_$;
1365

    
1366

    
1367
--
1368
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1369
--
1370

    
1371
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1372
idempotent
1373
';
1374

    
1375

    
1376
--
1377
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1378
--
1379

    
1380
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1381
    LANGUAGE sql
1382
    AS $_$
1383
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1384
included in the debug SQL */
1385
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1386
$_$;
1387

    
1388

    
1389
--
1390
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1391
--
1392

    
1393
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1394
    LANGUAGE sql
1395
    AS $_$
1396
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1397
||util._if($3, $$ CASCADE$$, ''::text))
1398
$_$;
1399

    
1400

    
1401
--
1402
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1403
--
1404

    
1405
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1406
idempotent
1407
';
1408

    
1409

    
1410
--
1411
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1412
--
1413

    
1414
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1415
    LANGUAGE sql
1416
    AS $_$
1417
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1418
$_$;
1419

    
1420

    
1421
--
1422
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1423
--
1424

    
1425
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1426
    LANGUAGE sql
1427
    AS $_$
1428
SELECT util.debug_print_func_call(util.quote_func_call(
1429
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1430
util.quote_typed($3)))
1431
;
1432
SELECT util.drop_relation(relation, $3)
1433
FROM util.show_relations_like($1, $2) relation
1434
;
1435
SELECT NULL::void; -- don't fold away functions called in previous query
1436
$_$;
1437

    
1438

    
1439
--
1440
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1441
--
1442

    
1443
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1444
    LANGUAGE sql
1445
    AS $_$
1446
SELECT util.drop_relation('TABLE', $1, $2)
1447
$_$;
1448

    
1449

    
1450
--
1451
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1452
--
1453

    
1454
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1455
idempotent
1456
';
1457

    
1458

    
1459
--
1460
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1461
--
1462

    
1463
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1464
    LANGUAGE sql
1465
    AS $_$
1466
SELECT util.drop_relation('VIEW', $1, $2)
1467
$_$;
1468

    
1469

    
1470
--
1471
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1472
--
1473

    
1474
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1475
idempotent
1476
';
1477

    
1478

    
1479
--
1480
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1481
--
1482

    
1483
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1484
    LANGUAGE sql IMMUTABLE
1485
    AS $_$
1486
SELECT util.array_fill($1, 0)
1487
$_$;
1488

    
1489

    
1490
--
1491
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1492
--
1493

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

    
1498

    
1499
--
1500
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1501
--
1502

    
1503
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1504
    LANGUAGE sql IMMUTABLE
1505
    AS $_$
1506
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1507
$_$;
1508

    
1509

    
1510
--
1511
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1512
--
1513

    
1514
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1515
    LANGUAGE sql IMMUTABLE
1516
    AS $_$
1517
SELECT regexp_replace($2, '("?)$', $1||'\1')
1518
$_$;
1519

    
1520

    
1521
--
1522
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1523
--
1524

    
1525
CREATE FUNCTION eval(queries text[]) RETURNS void
1526
    LANGUAGE sql
1527
    AS $_$
1528
SELECT util.eval(query) FROM unnest($1) query;
1529
SELECT NULL::void; -- don't fold away functions called in previous query
1530
$_$;
1531

    
1532

    
1533
--
1534
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1535
--
1536

    
1537
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1538
    LANGUAGE plpgsql
1539
    AS $$
1540
BEGIN
1541
	sql = util.view_def_to_orig(sql); -- restore user's intent
1542
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1543
	EXECUTE sql;
1544
END;
1545
$$;
1546

    
1547

    
1548
--
1549
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1550
--
1551

    
1552
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1553
    LANGUAGE plpgsql
1554
    AS $$
1555
BEGIN
1556
	PERFORM util.debug_print_sql(sql);
1557
	RETURN QUERY EXECUTE sql;
1558
END;
1559
$$;
1560

    
1561

    
1562
--
1563
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1564
--
1565

    
1566
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1567
col_type_null (*required*): NULL::col_type
1568
';
1569

    
1570

    
1571
--
1572
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1573
--
1574

    
1575
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1576
    LANGUAGE plpgsql
1577
    AS $$
1578
BEGIN
1579
	PERFORM util.debug_print_sql(sql);
1580
	RETURN QUERY EXECUTE sql;
1581
END;
1582
$$;
1583

    
1584

    
1585
--
1586
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1587
--
1588

    
1589
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1590
    LANGUAGE plpgsql
1591
    AS $$
1592
BEGIN
1593
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1594
	RETURN QUERY EXECUTE sql;
1595
END;
1596
$$;
1597

    
1598

    
1599
--
1600
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1601
--
1602

    
1603
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1604
    LANGUAGE plpgsql STABLE
1605
    AS $$
1606
DECLARE
1607
	ret_val ret_type_null%TYPE;
1608
BEGIN
1609
	PERFORM util.debug_print_sql(sql);
1610
	EXECUTE sql INTO STRICT ret_val;
1611
	RETURN ret_val;
1612
END;
1613
$$;
1614

    
1615

    
1616
--
1617
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1618
--
1619

    
1620
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1621
ret_type_null: NULL::ret_type
1622
';
1623

    
1624

    
1625
--
1626
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1627
--
1628

    
1629
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1630
    LANGUAGE sql
1631
    AS $_$
1632
SELECT util.eval2val($$SELECT $$||$1, $2)
1633
$_$;
1634

    
1635

    
1636
--
1637
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1638
--
1639

    
1640
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1641
ret_type_null: NULL::ret_type
1642
';
1643

    
1644

    
1645
--
1646
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1647
--
1648

    
1649
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1650
    LANGUAGE sql
1651
    AS $_$
1652
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1653
$_$;
1654

    
1655

    
1656
--
1657
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1658
--
1659

    
1660
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1661
sql: can be NULL, which will be passed through
1662
ret_type_null: NULL::ret_type
1663
';
1664

    
1665

    
1666
--
1667
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1668
--
1669

    
1670
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1671
    LANGUAGE sql STABLE
1672
    AS $_$
1673
SELECT col_name
1674
FROM unnest($2) s (col_name)
1675
WHERE util.col_exists(($1, col_name))
1676
$_$;
1677

    
1678

    
1679
--
1680
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1681
--
1682

    
1683
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1684
    LANGUAGE sql
1685
    SET client_min_messages TO 'error'
1686
    AS $_$
1687
/* `client_min_messages = ERROR`: EXPLAIN apparently runs IMMUTABLE functions in
1688
the query, so this prevents displaying any log messages printed by them */
1689
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1690
$_$;
1691

    
1692

    
1693
--
1694
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1695
--
1696

    
1697
CREATE FUNCTION explain2notice(sql text) RETURNS void
1698
    LANGUAGE sql
1699
    AS $_$
1700
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1701
$_$;
1702

    
1703

    
1704
--
1705
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1706
--
1707

    
1708
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1709
    LANGUAGE sql
1710
    AS $_$
1711
-- newline before and after to visually separate it from other debug info
1712
SELECT COALESCE($$
1713
EXPLAIN:
1714
$$||util.fold_explain_msg(util.explain2str($1))||$$
1715
$$, '')
1716
$_$;
1717

    
1718

    
1719
--
1720
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1721
--
1722

    
1723
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1724
    LANGUAGE plpgsql
1725
    AS $$
1726
BEGIN
1727
	RETURN util.explain2notice_msg(sql);
1728
EXCEPTION
1729
WHEN   syntax_error
1730
	OR invalid_cursor_definition -- "cannot open multi-query plan as cursor"
1731
	THEN RETURN NULL; -- non-explainable query
1732
	/* don't use util.is_explainable() because the list provided by Postgres
1733
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1734
	excludes some query types that are in fact EXPLAIN-able */
1735
END;
1736
$$;
1737

    
1738

    
1739
--
1740
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1741
--
1742

    
1743
CREATE FUNCTION explain2str(sql text) RETURNS text
1744
    LANGUAGE sql
1745
    AS $_$
1746
SELECT util.join_strs(explain, $$
1747
$$) FROM util.explain($1)
1748
$_$;
1749

    
1750

    
1751
SET default_tablespace = '';
1752

    
1753
SET default_with_oids = false;
1754

    
1755
--
1756
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1757
--
1758

    
1759
CREATE TABLE explain (
1760
    line text NOT NULL
1761
);
1762

    
1763

    
1764
--
1765
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1766
--
1767

    
1768
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1769
    LANGUAGE sql
1770
    AS $_$
1771
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1772
$$||quote_nullable($1)||$$
1773
)$$)
1774
$_$;
1775

    
1776

    
1777
--
1778
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1779
--
1780

    
1781
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1782
usage:
1783
PERFORM util.explain2table($$
1784
query
1785
$$);
1786
';
1787

    
1788

    
1789
--
1790
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1791
--
1792

    
1793
CREATE FUNCTION first_word(str text) RETURNS text
1794
    LANGUAGE sql IMMUTABLE
1795
    AS $_$
1796
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1797
$_$;
1798

    
1799

    
1800
--
1801
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1802
--
1803

    
1804
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1805
    LANGUAGE sql IMMUTABLE
1806
    AS $_$
1807
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1808
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1809
) END
1810
$_$;
1811

    
1812

    
1813
--
1814
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1815
--
1816

    
1817
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1818
ensures that an array will always have proper non-NULL dimensions
1819
';
1820

    
1821

    
1822
--
1823
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
1824
--
1825

    
1826
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1827
    LANGUAGE sql IMMUTABLE
1828
    AS $_$
1829
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1830
$_$;
1831

    
1832

    
1833
--
1834
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1835
--
1836

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

    
1857

    
1858
--
1859
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1860
--
1861

    
1862
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1863
idempotent
1864
';
1865

    
1866

    
1867
--
1868
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1869
--
1870

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

    
1884

    
1885
--
1886
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1887
--
1888

    
1889
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1890
    LANGUAGE sql STABLE
1891
    AS $_$
1892
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1893
$_$;
1894

    
1895

    
1896
--
1897
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1898
--
1899

    
1900
CREATE FUNCTION grants_users() RETURNS SETOF text
1901
    LANGUAGE sql IMMUTABLE
1902
    AS $$
1903
VALUES ('bien_read'), ('public_')
1904
$$;
1905

    
1906

    
1907
--
1908
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1909
--
1910

    
1911
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1912
    LANGUAGE sql IMMUTABLE
1913
    AS $_$
1914
SELECT substring($2 for length($1)) = $1
1915
$_$;
1916

    
1917

    
1918
--
1919
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1920
--
1921

    
1922
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1923
    LANGUAGE sql STABLE
1924
    AS $_$
1925
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1926
$_$;
1927

    
1928

    
1929
--
1930
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1931
--
1932

    
1933
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1934
    LANGUAGE sql IMMUTABLE
1935
    AS $_$
1936
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1937
$_$;
1938

    
1939

    
1940
--
1941
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1942
--
1943

    
1944
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1945
avoids repeating the same value for each key
1946
';
1947

    
1948

    
1949
--
1950
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1951
--
1952

    
1953
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1954
    LANGUAGE sql IMMUTABLE
1955
    AS $_$
1956
SELECT COALESCE($1, $2)
1957
$_$;
1958

    
1959

    
1960
--
1961
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1962
--
1963

    
1964
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1965
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1966
';
1967

    
1968

    
1969
--
1970
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
1971
--
1972

    
1973
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
1974
    LANGUAGE sql IMMUTABLE
1975
    AS $_$
1976
SELECT elem FROM unnest($1) elem ORDER BY row_number() OVER () DESC
1977
$_$;
1978

    
1979

    
1980
--
1981
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1982
--
1983

    
1984
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1985
    LANGUAGE sql
1986
    AS $_$
1987
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1988
$_$;
1989

    
1990

    
1991
--
1992
-- Name: is_castable(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1993
--
1994

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

    
2012

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

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

    
2021
ret_type_null: NULL::ret_type
2022
';
2023

    
2024

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

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

    
2037

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

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

    
2048

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

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

    
2059

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

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

    
2073

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

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

    
2084

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

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

    
2095

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

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

    
2106

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

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

    
2117

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

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

    
2128

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

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

    
2139

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

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

    
2148

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

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

    
2159

    
2160
--
2161
-- Name: keys_eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2162
--
2163

    
2164
CREATE FUNCTION keys_eq(left_ anyelement, right_ anyelement) RETURNS boolean
2165
    LANGUAGE sql STABLE
2166
    AS $_$
2167
SELECT keys($1) = keys($2)
2168
$_$;
2169

    
2170

    
2171
--
2172
-- Name: FUNCTION keys_eq(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
2173
--
2174

    
2175
COMMENT ON FUNCTION keys_eq(left_ anyelement, right_ anyelement) IS '
2176
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**)
2177
';
2178

    
2179

    
2180
--
2181
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2182
--
2183

    
2184
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2185
    LANGUAGE sql IMMUTABLE
2186
    AS $_$
2187
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2188
$_$;
2189

    
2190

    
2191
--
2192
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2193
--
2194

    
2195
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2196
    LANGUAGE plpgsql
2197
    AS $$
2198
DECLARE
2199
	errors_ct integer = 0;
2200
	loop_var loop_type_null%TYPE;
2201
BEGIN
2202
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2203
	LOOP
2204
		BEGIN
2205
			EXECUTE loop_body_sql USING loop_var;
2206
		EXCEPTION
2207
		WHEN OTHERS THEN
2208
			errors_ct = errors_ct+1;
2209
			PERFORM util.raise_error_warning(SQLERRM);
2210
		END;
2211
	END LOOP;
2212
	IF errors_ct > 0 THEN
2213
		-- can't raise exception because this would roll back the transaction
2214
		PERFORM util.raise_error_warning('there were '||errors_ct
2215
			||' errors: see the WARNINGs for details');
2216
	END IF;
2217
END;
2218
$$;
2219

    
2220

    
2221
--
2222
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2223
--
2224

    
2225
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2226
    LANGUAGE sql IMMUTABLE
2227
    AS $_$
2228
SELECT ltrim($1, $$
2229
$$)
2230
$_$;
2231

    
2232

    
2233
--
2234
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2235
--
2236

    
2237
CREATE FUNCTION map_filter_insert() RETURNS trigger
2238
    LANGUAGE plpgsql
2239
    AS $$
2240
BEGIN
2241
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2242
	RETURN new;
2243
END;
2244
$$;
2245

    
2246

    
2247
--
2248
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2249
--
2250

    
2251
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2252
    LANGUAGE plpgsql STABLE STRICT
2253
    AS $_$
2254
DECLARE
2255
    value text;
2256
BEGIN
2257
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2258
        INTO value USING key;
2259
    RETURN value;
2260
END;
2261
$_$;
2262

    
2263

    
2264
--
2265
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2266
--
2267

    
2268
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2269
    LANGUAGE sql IMMUTABLE
2270
    AS $_$
2271
SELECT util._map(util.nulls_map($1), $2)
2272
$_$;
2273

    
2274

    
2275
--
2276
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2277
--
2278

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

    
2282
[1] inlining of function calls, which is different from constant folding
2283
[2] _map()''s profiling query
2284
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2285
and map_nulls()''s profiling query
2286
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2287
both take ~920 ms.
2288
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.
2289
';
2290

    
2291

    
2292
--
2293
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2294
--
2295

    
2296
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2297
    LANGUAGE plpgsql STABLE STRICT
2298
    AS $_$
2299
BEGIN
2300
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2301
END;
2302
$_$;
2303

    
2304

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

    
2309
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2310
    LANGUAGE sql
2311
    AS $_$
2312
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2313
$$||util.ltrim_nl($2));
2314
-- make sure the created table has the correct estimated row count
2315
SELECT util.analyze_($1);
2316

    
2317
SELECT util.append_comment($1, '
2318
contents generated from:
2319
'||util.ltrim_nl(util.runnable_sql($2))||';
2320
');
2321
$_$;
2322

    
2323

    
2324
--
2325
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2326
--
2327

    
2328
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2329
idempotent
2330
';
2331

    
2332

    
2333
--
2334
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2335
--
2336

    
2337
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2338
    LANGUAGE sql
2339
    AS $_$
2340
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2341
$_$;
2342

    
2343

    
2344
--
2345
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2346
--
2347

    
2348
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2349
idempotent
2350
';
2351

    
2352

    
2353
--
2354
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2355
--
2356

    
2357
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2358
    LANGUAGE sql
2359
    AS $_$
2360
SELECT util.create_if_not_exists($$
2361
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2362
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2363
||quote_literal($2)||$$;
2364
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2365
constant
2366
';
2367
$$)
2368
$_$;
2369

    
2370

    
2371
--
2372
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2373
--
2374

    
2375
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2376
idempotent
2377
';
2378

    
2379

    
2380
--
2381
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2382
--
2383

    
2384
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2385
    LANGUAGE plpgsql STRICT
2386
    AS $_$
2387
DECLARE
2388
    type regtype = util.typeof(expr, col.table_::text::regtype);
2389
    col_name_sql text = quote_ident(col.name);
2390
BEGIN
2391
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2392
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2393
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2394
$$||expr||$$;
2395
$$);
2396
END;
2397
$_$;
2398

    
2399

    
2400
--
2401
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2402
--
2403

    
2404
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2405
idempotent
2406
';
2407

    
2408

    
2409
--
2410
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2411
--
2412

    
2413
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
2414
    LANGUAGE sql IMMUTABLE
2415
    AS $_$
2416
SELECT
2417
$$SELECT
2418
$$||$3||$$
2419
FROM      $$||$1||$$ left_
2420
FULL JOIN $$||$2||$$ right_
2421
ON $$||$4||$$
2422
WHERE $$||$5||$$
2423
ORDER BY left_, right_
2424
$$
2425
$_$;
2426

    
2427

    
2428
--
2429
-- Name: mk_drop_from_create(text); Type: FUNCTION; Schema: util; Owner: -
2430
--
2431

    
2432
CREATE FUNCTION mk_drop_from_create(create_cmd text) RETURNS text
2433
    LANGUAGE sql IMMUTABLE
2434
    AS $_$
2435
SELECT $$DROP $$||(util.regexp_match($1,
2436
-- match first CREATE, *if* no DROP came before it
2437
'(?m)\A(?:^(?!DROP\y).*\n)*?^CREATE(?: OR REPLACE)? ((?:)??[[:upper:]]+ .*?)(?: AS(?: (?:SELECT\y.*)?)?)?$'
2438
	/* (?:)?? makes the surrounding () group non-greedy, so that (?: AS ?)?
2439
	works properly (due to nonstandard Postgres regexp behavior:
2440
	http://www.postgresql.org/docs/9.3/static/functions-matching.html#POSIX-MATCHING-RULES) */
2441
))[1]||$$;$$
2442
$_$;
2443

    
2444

    
2445
--
2446
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2447
--
2448

    
2449
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2450
    LANGUAGE sql
2451
    AS $_$
2452
-- keys()
2453
SELECT util.mk_keys_func($1, ARRAY(
2454
SELECT col FROM util.typed_cols($1) col
2455
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2456
));
2457

    
2458
-- values_()
2459
SELECT util.mk_keys_func($1, COALESCE(
2460
	NULLIF(ARRAY(
2461
	SELECT col FROM util.typed_cols($1) col
2462
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2463
	), ARRAY[]::util.col_cast[])
2464
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2465
, 'values_');
2466
$_$;
2467

    
2468

    
2469
--
2470
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2471
--
2472

    
2473
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2474
    LANGUAGE sql
2475
    AS $_$
2476
SELECT util.create_if_not_exists($$
2477
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2478
($$||util.mk_typed_cols_list($2)||$$);
2479
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2480
autogenerated
2481
';
2482
$$);
2483

    
2484
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2485
$_$;
2486

    
2487

    
2488
--
2489
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2490
--
2491

    
2492
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2493
    LANGUAGE sql
2494
    AS $_$
2495
SELECT util.create_if_not_exists($$
2496
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2497
||util.qual_name($1)||$$)
2498
  RETURNS $$||util.qual_name($2)||$$ AS
2499
$BODY1$
2500
SELECT ROW($$||
2501
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2502
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2503
$BODY1$
2504
  LANGUAGE sql IMMUTABLE
2505
  COST 100;
2506
$$);
2507
$_$;
2508

    
2509

    
2510
--
2511
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2512
--
2513

    
2514
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2515
    LANGUAGE sql
2516
    AS $_$
2517
SELECT util.create_if_not_exists($$
2518
CREATE TABLE $$||$1||$$
2519
(
2520
    LIKE util.map INCLUDING ALL
2521
);
2522

    
2523
CREATE TRIGGER map_filter_insert
2524
  BEFORE INSERT
2525
  ON $$||$1||$$
2526
  FOR EACH ROW
2527
  EXECUTE PROCEDURE util.map_filter_insert();
2528
$$)
2529
$_$;
2530

    
2531

    
2532
--
2533
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2534
--
2535

    
2536
CREATE FUNCTION mk_not_null(text) RETURNS text
2537
    LANGUAGE sql IMMUTABLE
2538
    AS $_$
2539
SELECT COALESCE($1, '<NULL>')
2540
$_$;
2541

    
2542

    
2543
--
2544
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2545
--
2546

    
2547
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2548
    LANGUAGE sql IMMUTABLE
2549
    AS $_$
2550
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2551
util.qual_name((unnest).type), ''), '')
2552
FROM unnest($1)
2553
$_$;
2554

    
2555

    
2556
--
2557
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2558
--
2559

    
2560
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2561
    LANGUAGE sql IMMUTABLE
2562
    AS $_$
2563
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2564
$_$;
2565

    
2566

    
2567
--
2568
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2569
--
2570

    
2571
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2572
auto-appends util to the search_path to enable use of util operators
2573
';
2574

    
2575

    
2576
--
2577
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2578
--
2579

    
2580
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2581
    LANGUAGE sql STABLE
2582
    AS $_$
2583
SELECT COALESCE($$COMMENT ON $$||util.relation_type($1)||$$ $$||$1||$$ IS $$
2584
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2585
$_$;
2586

    
2587

    
2588
--
2589
-- Name: mk_set_relation_metadata(regclass); Type: FUNCTION; Schema: util; Owner: -
2590
--
2591

    
2592
CREATE FUNCTION mk_set_relation_metadata(relation regclass) RETURNS text
2593
    LANGUAGE sql STABLE
2594
    AS $_$
2595
SELECT util.show_grants_for($1)
2596
||util.show_set_comment($1)||$$
2597
$$
2598
$_$;
2599

    
2600

    
2601
--
2602
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2603
--
2604

    
2605
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2606
    LANGUAGE sql IMMUTABLE
2607
    AS $_$
2608
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2609
$_$;
2610

    
2611

    
2612
--
2613
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2614
--
2615

    
2616
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2617
    LANGUAGE sql IMMUTABLE
2618
    AS $_$
2619
/* debug_print_return_value() needed because this function is used with EXECUTE
2620
rather than util.eval() (in order to affect the calling function), so the
2621
search_path would not otherwise be printed */
2622
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2623
||$$ search_path TO $$||$1
2624
$_$;
2625

    
2626

    
2627
--
2628
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2629
--
2630

    
2631
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2632
    LANGUAGE sql
2633
    AS $_$
2634
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2635
$_$;
2636

    
2637

    
2638
--
2639
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2640
--
2641

    
2642
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2643
idempotent
2644
';
2645

    
2646

    
2647
--
2648
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2649
--
2650

    
2651
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2652
    LANGUAGE plpgsql STRICT
2653
    AS $_$
2654
DECLARE
2655
	view_qual_name text = util.qual_name(view_);
2656
BEGIN
2657
	EXECUTE $$
2658
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2659
  RETURNS SETOF $$||view_||$$ AS
2660
$BODY1$
2661
SELECT * FROM $$||view_qual_name||$$
2662
ORDER BY sort_col
2663
LIMIT $1 OFFSET $2
2664
$BODY1$
2665
  LANGUAGE sql STABLE
2666
  COST 100
2667
  ROWS 1000
2668
$$;
2669
	
2670
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2671
END;
2672
$_$;
2673

    
2674

    
2675
--
2676
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2677
--
2678

    
2679
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2680
    LANGUAGE plpgsql STRICT
2681
    AS $_$
2682
DECLARE
2683
	view_qual_name text = util.qual_name(view_);
2684
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2685
BEGIN
2686
	EXECUTE $$
2687
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2688
  RETURNS integer AS
2689
$BODY1$
2690
SELECT $$||quote_ident(row_num_col)||$$
2691
FROM $$||view_qual_name||$$
2692
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2693
LIMIT 1
2694
$BODY1$
2695
  LANGUAGE sql STABLE
2696
  COST 100;
2697
$$;
2698
	
2699
	EXECUTE $$
2700
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2701
  RETURNS SETOF $$||view_||$$ AS
2702
$BODY1$
2703
SELECT * FROM $$||view_qual_name||$$
2704
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2705
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2706
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2707
ORDER BY $$||quote_ident(row_num_col)||$$
2708
$BODY1$
2709
  LANGUAGE sql STABLE
2710
  COST 100
2711
  ROWS 1000
2712
$$;
2713
	
2714
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2715
END;
2716
$_$;
2717

    
2718

    
2719
--
2720
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2721
--
2722

    
2723
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2724
    LANGUAGE plpgsql STRICT
2725
    AS $_$
2726
DECLARE
2727
	view_qual_name text = util.qual_name(view_);
2728
BEGIN
2729
	EXECUTE $$
2730
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2731
  RETURNS SETOF $$||view_||$$
2732
  SET enable_sort TO 'off'
2733
  AS
2734
$BODY1$
2735
SELECT * FROM $$||view_qual_name||$$($2, $3)
2736
$BODY1$
2737
  LANGUAGE sql STABLE
2738
  COST 100
2739
  ROWS 1000
2740
;
2741
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2742
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2743
If you want to run EXPLAIN and get expanded output, use the regular subset
2744
function instead. (When a config param is set on a function, EXPLAIN produces
2745
just a function scan.)
2746
';
2747
$$;
2748
END;
2749
$_$;
2750

    
2751

    
2752
--
2753
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2754
--
2755

    
2756
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2757
creates subset function which turns off enable_sort
2758
';
2759

    
2760

    
2761
--
2762
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2763
--
2764

    
2765
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2766
    LANGUAGE sql IMMUTABLE
2767
    AS $_$
2768
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2769
util.qual_name((unnest).type), ', '), '')
2770
FROM unnest($1)
2771
$_$;
2772

    
2773

    
2774
--
2775
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2776
--
2777

    
2778
CREATE FUNCTION name(table_ regclass) RETURNS text
2779
    LANGUAGE sql STABLE
2780
    AS $_$
2781
SELECT relname::text FROM pg_class WHERE oid = $1
2782
$_$;
2783

    
2784

    
2785
--
2786
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2787
--
2788

    
2789
CREATE FUNCTION name(type regtype) RETURNS text
2790
    LANGUAGE sql STABLE
2791
    AS $_$
2792
SELECT typname::text FROM pg_type WHERE oid = $1
2793
$_$;
2794

    
2795

    
2796
--
2797
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2798
--
2799

    
2800
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2801
    LANGUAGE sql IMMUTABLE
2802
    AS $_$
2803
SELECT octet_length($1) >= util.namedatalen() - $2
2804
$_$;
2805

    
2806

    
2807
--
2808
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2809
--
2810

    
2811
CREATE FUNCTION namedatalen() RETURNS integer
2812
    LANGUAGE sql IMMUTABLE
2813
    AS $$
2814
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2815
$$;
2816

    
2817

    
2818
--
2819
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2820
--
2821

    
2822
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2823
    LANGUAGE sql IMMUTABLE
2824
    AS $_$
2825
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2826
$_$;
2827

    
2828

    
2829
--
2830
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2831
--
2832

    
2833
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2834
    LANGUAGE sql IMMUTABLE
2835
    AS $_$
2836
SELECT $1 IS NOT NULL
2837
$_$;
2838

    
2839

    
2840
--
2841
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2842
--
2843

    
2844
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2845
    LANGUAGE sql IMMUTABLE
2846
    AS $_$
2847
SELECT util.hstore($1, NULL) || '*=>*'
2848
$_$;
2849

    
2850

    
2851
--
2852
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2853
--
2854

    
2855
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2856
for use with _map()
2857
';
2858

    
2859

    
2860
--
2861
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2862
--
2863

    
2864
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2865
    LANGUAGE sql IMMUTABLE
2866
    AS $_$
2867
SELECT $2 + COALESCE($1, 0)
2868
$_$;
2869

    
2870

    
2871
--
2872
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2873
--
2874

    
2875
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2876
    LANGUAGE sql STABLE
2877
    AS $_$
2878
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2879
$_$;
2880

    
2881

    
2882
--
2883
-- Name: pg_get_viewdef(regclass); Type: FUNCTION; Schema: util; Owner: -
2884
--
2885

    
2886
CREATE FUNCTION pg_get_viewdef(view_ regclass) RETURNS text
2887
    LANGUAGE sql STABLE
2888
    AS $_$
2889
SELECT util.view_def_to_orig(pg_catalog.pg_get_viewdef($1))
2890
$_$;
2891

    
2892

    
2893
--
2894
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2895
--
2896

    
2897
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2898
    LANGUAGE sql
2899
    AS $_$
2900
SELECT util.eval($$INSERT INTO $$||$1||$$
2901
$$||util.ltrim_nl($2));
2902
-- make sure the created table has the correct estimated row count
2903
SELECT util.analyze_($1);
2904
$_$;
2905

    
2906

    
2907
--
2908
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2909
--
2910

    
2911
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2912
    LANGUAGE sql IMMUTABLE
2913
    AS $_$
2914
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2915
$_$;
2916

    
2917

    
2918
--
2919
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2920
--
2921

    
2922
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2923
    LANGUAGE sql
2924
    AS $_$
2925
SELECT util.set_comment($1, concat($2, util.comment($1)))
2926
$_$;
2927

    
2928

    
2929
--
2930
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2931
--
2932

    
2933
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2934
comment: must start and end with a newline
2935
';
2936

    
2937

    
2938
--
2939
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2940
--
2941

    
2942
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2943
    LANGUAGE sql IMMUTABLE
2944
    AS $_$
2945
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2946
$_$;
2947

    
2948

    
2949
--
2950
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2951
--
2952

    
2953
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2954
    LANGUAGE sql STABLE
2955
    SET search_path TO pg_temp
2956
    AS $_$
2957
SELECT $1::text
2958
$_$;
2959

    
2960

    
2961
--
2962
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2963
--
2964

    
2965
CREATE FUNCTION qual_name(type regtype) RETURNS text
2966
    LANGUAGE sql STABLE
2967
    SET search_path TO pg_temp
2968
    AS $_$
2969
SELECT $1::text
2970
$_$;
2971

    
2972

    
2973
--
2974
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2975
--
2976

    
2977
COMMENT ON FUNCTION qual_name(type regtype) IS '
2978
a type''s schema-qualified name
2979
';
2980

    
2981

    
2982
--
2983
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2984
--
2985

    
2986
CREATE FUNCTION qual_name(type unknown) RETURNS text
2987
    LANGUAGE sql STABLE
2988
    AS $_$
2989
SELECT util.qual_name($1::text::regtype)
2990
$_$;
2991

    
2992

    
2993
--
2994
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2995
--
2996

    
2997
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2998
    LANGUAGE sql IMMUTABLE
2999
    AS $_$
3000
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
3001
$_$;
3002

    
3003

    
3004
--
3005
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3006
--
3007

    
3008
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
3009
    LANGUAGE sql IMMUTABLE
3010
    AS $_$
3011
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
3012
$_$;
3013

    
3014

    
3015
--
3016
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
3017
--
3018

    
3019
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
3020
    LANGUAGE sql IMMUTABLE
3021
    AS $_$
3022
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
3023
$_$;
3024

    
3025

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

    
3030
CREATE FUNCTION raise(type text, msg text) RETURNS void
3031
    LANGUAGE sql IMMUTABLE
3032
    AS $_X$
3033
SELECT util.eval($$
3034
CREATE OR REPLACE FUNCTION pg_temp.__raise()
3035
  RETURNS void AS
3036
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
3037
$__BODY1$
3038
BEGIN
3039
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
3040
END;
3041
$__BODY1$
3042
  LANGUAGE plpgsql IMMUTABLE
3043
  COST 100;
3044
$$, verbose_ := false);
3045

    
3046
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
3047
$_X$;
3048

    
3049

    
3050
--
3051
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
3052
--
3053

    
3054
COMMENT ON FUNCTION raise(type text, msg text) IS '
3055
type: a log level from
3056
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
3057
or a condition name from
3058
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
3059
';
3060

    
3061

    
3062
--
3063
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
3064
--
3065

    
3066
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3067
    LANGUAGE sql IMMUTABLE
3068
    AS $_$
3069
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3070
$_$;
3071

    
3072

    
3073
--
3074
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3075
--
3076

    
3077
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3078
    LANGUAGE plpgsql IMMUTABLE STRICT
3079
    AS $$
3080
BEGIN
3081
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3082
END;
3083
$$;
3084

    
3085

    
3086
--
3087
-- Name: range(numeric, numeric); Type: FUNCTION; Schema: util; Owner: -
3088
--
3089

    
3090
CREATE FUNCTION range(lower numeric, upper numeric) RETURNS numrange
3091
    LANGUAGE sql IMMUTABLE
3092
    AS $_$
3093
SELECT numrange($1, $2, '[]')
3094
$_$;
3095

    
3096

    
3097
--
3098
-- Name: recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3099
--
3100

    
3101
CREATE FUNCTION recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
3102
    LANGUAGE plpgsql
3103
    AS $_$
3104
DECLARE
3105
	PG_EXCEPTION_DETAIL text;
3106
	restore_views_info util.restore_views_info;
3107
BEGIN
3108
	restore_views_info = util.save_drop_views(users);
3109
	
3110
	-- trigger the dependent_objects_still_exist exception
3111
	PERFORM util.eval(COALESCE(util.mk_drop_from_create(cmd), '')||cmd);
3112
		-- *not* CASCADE; it must trigger an exception
3113
	
3114
	PERFORM util.restore_views(restore_views_info);
3115
EXCEPTION
3116
WHEN dependent_objects_still_exist THEN
3117
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
3118
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
3119
	users = array(SELECT * FROM util.regexp_matches_group(
3120
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$'));
3121
		-- will be in forward dependency order
3122
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
3123
	PERFORM util.debug_print_var('users', users);
3124
	IF util.is_empty(users) THEN RAISE; END IF;
3125
	PERFORM util.recreate(cmd, users);
3126
END;
3127
$_$;
3128

    
3129

    
3130
--
3131
-- Name: FUNCTION recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
3132
--
3133

    
3134
COMMENT ON FUNCTION recreate(cmd text, users text[]) IS '
3135
the appropriate drop statement will be added automatically.
3136

    
3137
usage:
3138
SELECT util.recreate($$
3139
CREATE VIEW schema.main_view AS _;
3140

    
3141
-- manually restore views that need to be updated for the changes
3142
CREATE VIEW schema.dependent_view AS _;
3143
$$);
3144

    
3145
idempotent
3146

    
3147
users: not necessary to provide this because it will be autopopulated
3148
';
3149

    
3150

    
3151
--
3152
-- Name: recreate_view(regclass, text, text); Type: FUNCTION; Schema: util; Owner: -
3153
--
3154

    
3155
CREATE FUNCTION recreate_view(view_ regclass, view_query text DEFAULT NULL::text, dependent_view_changes text DEFAULT ''::text) RETURNS void
3156
    LANGUAGE sql
3157
    AS $_$
3158
SELECT util.recreate($$
3159
CREATE VIEW $$||$1||$$ AS 
3160
$$||COALESCE($2, pg_get_viewdef($1))||$$;
3161
$$||util.mk_set_relation_metadata($1)||$$
3162

    
3163
-- manually restore views that need to be updated for the changes
3164
$$||$3||$$
3165
$$);
3166
$_$;
3167

    
3168

    
3169
--
3170
-- Name: FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text); Type: COMMENT; Schema: util; Owner: -
3171
--
3172

    
3173
COMMENT ON FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text) IS '
3174
usage:
3175
SELECT util.recreate_view(''schema.main_view'', $$
3176
SELECT __
3177
$$, $$
3178
CREATE VIEW schema.dependent_view AS 
3179
__;
3180
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3181
$$);
3182

    
3183
if view has already been modified:
3184
SELECT util.recreate_view(''schema.main_view'', dependent_view_changes := $$
3185
CREATE VIEW schema.dependent_view AS 
3186
__;
3187
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3188
$$);
3189

    
3190
idempotent
3191
';
3192

    
3193

    
3194
--
3195
-- Name: regexp_match(text, text); Type: FUNCTION; Schema: util; Owner: -
3196
--
3197

    
3198
CREATE FUNCTION regexp_match(str text, re text) RETURNS text[]
3199
    LANGUAGE sql IMMUTABLE
3200
    AS $_$
3201
SELECT match FROM regexp_matches($1, $2) match LIMIT 1/*only 1st match*/
3202
$_$;
3203

    
3204

    
3205
--
3206
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3207
--
3208

    
3209
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3210
    LANGUAGE sql IMMUTABLE
3211
    AS $_$
3212
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3213
$_$;
3214

    
3215

    
3216
--
3217
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3218
--
3219

    
3220
CREATE FUNCTION regexp_quote(str text) RETURNS text
3221
    LANGUAGE sql IMMUTABLE
3222
    AS $_$
3223
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3224
$_$;
3225

    
3226

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

    
3231
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3232
    LANGUAGE sql IMMUTABLE
3233
    AS $_$
3234
SELECT (CASE WHEN right($1, 1) = ')'
3235
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3236
$_$;
3237

    
3238

    
3239
--
3240
-- Name: relation_exists(text); Type: FUNCTION; Schema: util; Owner: -
3241
--
3242

    
3243
CREATE FUNCTION relation_exists(relation text) RETURNS boolean
3244
    LANGUAGE sql STABLE
3245
    AS $_$
3246
SELECT $1 IS NOT NULL AND util.is_castable($1, NULL::regclass)
3247
$_$;
3248

    
3249

    
3250
--
3251
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3252
--
3253

    
3254
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3255
    LANGUAGE sql STABLE
3256
    AS $_$
3257
SELECT util.relation_type(util.relation_type_char($1))
3258
$_$;
3259

    
3260

    
3261
--
3262
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3263
--
3264

    
3265
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3266
    LANGUAGE sql IMMUTABLE
3267
    AS $_$
3268
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3269
$_$;
3270

    
3271

    
3272
--
3273
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3274
--
3275

    
3276
CREATE FUNCTION relation_type(type regtype) RETURNS text
3277
    LANGUAGE sql IMMUTABLE
3278
    AS $$
3279
SELECT 'TYPE'::text
3280
$$;
3281

    
3282

    
3283
--
3284
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
3285
--
3286

    
3287
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3288
    LANGUAGE sql STABLE
3289
    AS $_$
3290
SELECT relkind FROM pg_class WHERE oid = $1
3291
$_$;
3292

    
3293

    
3294
--
3295
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
3296
--
3297

    
3298
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3299
    LANGUAGE sql
3300
    AS $_$
3301
/* can't have in_table/out_table inherit from *each other*, because inheritance
3302
also causes the rows of the parent table to be included in the child table.
3303
instead, they need to inherit from a common, empty table. */
3304
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3305
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3306
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3307
SELECT util.inherit($2, $4);
3308
SELECT util.inherit($3, $4);
3309

    
3310
SELECT util.rematerialize_query($1, $$
3311
SELECT * FROM util.diff(
3312
  $$||util.quote_typed($2)||$$
3313
, $$||util.quote_typed($3)||$$
3314
, NULL::$$||$4||$$)
3315
$$);
3316

    
3317
/* the table unfortunately cannot be *materialized* in human-readable form,
3318
because this would create column name collisions between the two sides */
3319
SELECT util.prepend_comment($1, '
3320
to view this table in human-readable form (with each side''s tuple column
3321
expanded to its component fields):
3322
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3323

    
3324
to display NULL values that are extra or missing:
3325
SELECT * FROM '||$1||';
3326
');
3327
$_$;
3328

    
3329

    
3330
--
3331
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3332
--
3333

    
3334
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3335
type_table (*required*): table to create as the shared base type
3336
';
3337

    
3338

    
3339
--
3340
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3341
--
3342

    
3343
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3344
    LANGUAGE sql
3345
    AS $_$
3346
SELECT util.drop_table($1);
3347
SELECT util.materialize_query($1, $2);
3348
$_$;
3349

    
3350

    
3351
--
3352
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3353
--
3354

    
3355
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3356
idempotent, but repeats action each time
3357
';
3358

    
3359

    
3360
--
3361
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3362
--
3363

    
3364
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3365
    LANGUAGE sql
3366
    AS $_$
3367
SELECT util.drop_table($1);
3368
SELECT util.materialize_view($1, $2);
3369
$_$;
3370

    
3371

    
3372
--
3373
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3374
--
3375

    
3376
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3377
idempotent, but repeats action each time
3378
';
3379

    
3380

    
3381
--
3382
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3383
--
3384

    
3385
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3386
    LANGUAGE sql
3387
    AS $_$
3388
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3389
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3390
FROM util.col_names($1::text::regtype) f (name);
3391
SELECT NULL::void; -- don't fold away functions called in previous query
3392
$_$;
3393

    
3394

    
3395
--
3396
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3397
--
3398

    
3399
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3400
idempotent
3401
';
3402

    
3403

    
3404
--
3405
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3406
--
3407

    
3408
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3409
    LANGUAGE sql
3410
    AS $_$
3411
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3412
included in the debug SQL */
3413
SELECT util.rename_relation(util.qual_name($1), $2)
3414
$_$;
3415

    
3416

    
3417
--
3418
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3419
--
3420

    
3421
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3422
    LANGUAGE sql
3423
    AS $_$
3424
/* 'ALTER TABLE can be used with views too'
3425
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3426
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3427
||quote_ident($2))
3428
$_$;
3429

    
3430

    
3431
--
3432
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3433
--
3434

    
3435
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3436
idempotent
3437
';
3438

    
3439

    
3440
--
3441
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3442
--
3443

    
3444
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3445
    LANGUAGE sql IMMUTABLE
3446
    AS $_$
3447
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3448
$_$;
3449

    
3450

    
3451
--
3452
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3453
--
3454

    
3455
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3456
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 
3457
';
3458

    
3459

    
3460
--
3461
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3462
--
3463

    
3464
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3465
    LANGUAGE sql
3466
    AS $_$
3467
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3468
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3469
SELECT util.set_col_names($1, $2);
3470
$_$;
3471

    
3472

    
3473
--
3474
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3475
--
3476

    
3477
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3478
idempotent.
3479
alters the names table, so it will need to be repopulated after running this function.
3480
';
3481

    
3482

    
3483
--
3484
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3485
--
3486

    
3487
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3488
    LANGUAGE sql
3489
    AS $_$
3490
SELECT util.drop_table($1);
3491
SELECT util.mk_map_table($1);
3492
$_$;
3493

    
3494

    
3495
--
3496
-- Name: restore_views(restore_views_info); Type: FUNCTION; Schema: util; Owner: -
3497
--
3498

    
3499
CREATE FUNCTION restore_views(restore_views_info) RETURNS void
3500
    LANGUAGE sql
3501
    AS $_$
3502
SELECT util.debug_print_var('views', $1);
3503
SELECT util.create_if_not_exists((view_).def, (view_).path)
3504
	/* need to specify view name for manual existence check, in case view def
3505
	becomes invalid, which would produce nonstandard (uncatchable) exception */
3506
FROM unnest($1.views) view_; -- in forward dependency order
3507
	/* create_if_not_exists() rather than eval(), because cmd might manually
3508
	re-create a deleted dependent view, causing it to already exist */
3509
SELECT NULL::void; -- don't fold away functions called in previous query
3510
$_$;
3511

    
3512

    
3513
--
3514
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3515
--
3516

    
3517
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3518
    LANGUAGE sql
3519
    AS $_$
3520
SELECT util.drop_column($1, $2, force := true)
3521
$_$;
3522

    
3523

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

    
3528
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3529
    LANGUAGE sql IMMUTABLE
3530
    AS $_$
3531
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3532
$_$;
3533

    
3534

    
3535
--
3536
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3537
--
3538

    
3539
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3540
    LANGUAGE sql IMMUTABLE
3541
    AS $_$
3542
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3543
ELSE util.mk_set_search_path(for_printing := true)||$$;
3544
$$ END)||$1
3545
$_$;
3546

    
3547

    
3548
--
3549
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3550
--
3551

    
3552
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3553
    LANGUAGE plpgsql STRICT
3554
    AS $$
3555
DECLARE
3556
	result text = NULL;
3557
BEGIN
3558
	BEGIN
3559
		result = util.show_create_view(view_, replace := false);
3560
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3561
			(eg. invalid_table_definition), instead of the standard
3562
			duplicate_table exception caught by util.create_if_not_exists() */
3563
		PERFORM util.drop_view(view_);
3564
	EXCEPTION
3565
		WHEN undefined_table THEN NULL;
3566
	END;
3567
	RETURN result;
3568
END;
3569
$$;
3570

    
3571

    
3572
--
3573
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3574
--
3575

    
3576
CREATE FUNCTION save_drop_views(views text[]) RETURNS restore_views_info
3577
    LANGUAGE sql
3578
    AS $_$
3579
SELECT ROW(/*return in forward dependency order*/util.array_reverse(array(
3580
SELECT (view_, util.save_drop_view(view_))::util.db_item
3581
FROM unnest(/*drop in reverse dependency order*/util.array_reverse($1)) view_
3582
)))::util.restore_views_info
3583
$_$;
3584

    
3585

    
3586
--
3587
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3588
--
3589

    
3590
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3591
    LANGUAGE sql STABLE
3592
    AS $_$
3593
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3594
$_$;
3595

    
3596

    
3597
--
3598
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3599
--
3600

    
3601
CREATE FUNCTION schema(table_ regclass) RETURNS text
3602
    LANGUAGE sql STABLE
3603
    AS $_$
3604
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3605
$_$;
3606

    
3607

    
3608
--
3609
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3610
--
3611

    
3612
CREATE FUNCTION schema(type regtype) RETURNS text
3613
    LANGUAGE sql STABLE
3614
    AS $_$
3615
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3616
$_$;
3617

    
3618

    
3619
--
3620
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3621
--
3622

    
3623
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3624
    LANGUAGE sql STABLE
3625
    AS $_$
3626
SELECT util.schema(pg_typeof($1))
3627
$_$;
3628

    
3629

    
3630
--
3631
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3632
--
3633

    
3634
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3635
    LANGUAGE sql STABLE
3636
    AS $_$
3637
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3638
$_$;
3639

    
3640

    
3641
--
3642
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3643
--
3644

    
3645
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3646
a schema bundle is a group of schemas with a common prefix
3647
';
3648

    
3649

    
3650
--
3651
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3652
--
3653

    
3654
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3655
    LANGUAGE sql
3656
    AS $_$
3657
SELECT util.schema_rename(old_schema,
3658
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3659
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3660
SELECT NULL::void; -- don't fold away functions called in previous query
3661
$_$;
3662

    
3663

    
3664
--
3665
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3666
--
3667

    
3668
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3669
    LANGUAGE plpgsql
3670
    AS $$
3671
BEGIN
3672
	-- don't schema_bundle_rm() the schema_bundle to keep!
3673
	IF replace = with_ THEN RETURN; END IF;
3674
	
3675
	PERFORM util.schema_bundle_rm(replace);
3676
	PERFORM util.schema_bundle_rename(with_, replace);
3677
END;
3678
$$;
3679

    
3680

    
3681
--
3682
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3683
--
3684

    
3685
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3686
    LANGUAGE sql
3687
    AS $_$
3688
SELECT util.schema_rm(schema)
3689
FROM util.schema_bundle_get_schemas($1) f (schema);
3690
SELECT NULL::void; -- don't fold away functions called in previous query
3691
$_$;
3692

    
3693

    
3694
--
3695
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3696
--
3697

    
3698
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3699
    LANGUAGE sql STABLE
3700
    AS $_$
3701
SELECT quote_ident(util.schema($1))
3702
$_$;
3703

    
3704

    
3705
--
3706
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3707
--
3708

    
3709
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3710
    LANGUAGE sql IMMUTABLE
3711
    AS $_$
3712
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3713
$_$;
3714

    
3715

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

    
3720
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3721
    LANGUAGE sql STABLE
3722
    AS $_$
3723
SELECT oid FROM pg_namespace WHERE nspname = $1
3724
$_$;
3725

    
3726

    
3727
--
3728
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3729
--
3730

    
3731
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3732
    LANGUAGE sql IMMUTABLE
3733
    AS $_$
3734
SELECT util.schema_regexp(schema_anchor := $1)
3735
$_$;
3736

    
3737

    
3738
--
3739
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3740
--
3741

    
3742
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3743
    LANGUAGE sql IMMUTABLE
3744
    AS $_$
3745
SELECT util.str_equality_regexp(util.schema($1))
3746
$_$;
3747

    
3748

    
3749
--
3750
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3751
--
3752

    
3753
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3754
    LANGUAGE sql
3755
    AS $_$
3756
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3757
$_$;
3758

    
3759

    
3760
--
3761
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3762
--
3763

    
3764
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3765
    LANGUAGE plpgsql
3766
    AS $$
3767
BEGIN
3768
	-- don't schema_rm() the schema to keep!
3769
	IF replace = with_ THEN RETURN; END IF;
3770
	
3771
	PERFORM util.schema_rm(replace);
3772
	PERFORM util.schema_rename(with_, replace);
3773
END;
3774
$$;
3775

    
3776

    
3777
--
3778
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3779
--
3780

    
3781
CREATE FUNCTION schema_rm(schema text) RETURNS void
3782
    LANGUAGE sql
3783
    AS $_$
3784
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3785
$_$;
3786

    
3787

    
3788
--
3789
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3790
--
3791

    
3792
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3793
    LANGUAGE sql
3794
    AS $_$
3795
SELECT util.eval(
3796
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3797
$_$;
3798

    
3799

    
3800
--
3801
-- Name: seq__create(text, integer); Type: FUNCTION; Schema: util; Owner: -
3802
--
3803

    
3804
CREATE FUNCTION seq__create(seq text, start integer DEFAULT 0) RETURNS void
3805
    LANGUAGE sql
3806
    AS $_$
3807
SELECT util.create_if_not_exists($$CREATE SEQUENCE $$||$1||$$ MINVALUE $$||$2,
3808
$1)
3809
$_$;
3810

    
3811

    
3812
--
3813
-- Name: FUNCTION seq__create(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
3814
--
3815

    
3816
COMMENT ON FUNCTION seq__create(seq text, start integer) IS '
3817
idempotent
3818
';
3819

    
3820

    
3821
--
3822
-- Name: seq__reset(text, integer); Type: FUNCTION; Schema: util; Owner: -
3823
--
3824

    
3825
CREATE FUNCTION seq__reset(seq text, start integer DEFAULT 0) RETURNS void
3826
    LANGUAGE sql
3827
    AS $_$
3828
SELECT util.seq__create($1, $2);
3829
SELECT util.eval($$ALTER SEQUENCE $$||$1||$$ RESTART$$);
3830
$_$;
3831

    
3832

    
3833
--
3834
-- Name: FUNCTION seq__reset(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
3835
--
3836

    
3837
COMMENT ON FUNCTION seq__reset(seq text, start integer) IS '
3838
creates sequence if doesn''t exist
3839

    
3840
idempotent
3841

    
3842
start: *note*: only used if sequence doesn''t exist
3843
';
3844

    
3845

    
3846
--
3847
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3848
--
3849

    
3850
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3851
    LANGUAGE plpgsql STRICT
3852
    AS $_$
3853
DECLARE
3854
    old text[] = ARRAY(SELECT util.col_names(table_));
3855
    new text[] = ARRAY(SELECT util.map_values(names));
3856
BEGIN
3857
    old = old[1:array_length(new, 1)]; -- truncate to same length
3858
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3859
||$$ TO $$||quote_ident(value))
3860
    FROM each(hstore(old, new))
3861
    WHERE value != key -- not same name
3862
    ;
3863
END;
3864
$_$;
3865

    
3866

    
3867
--
3868
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3869
--
3870

    
3871
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3872
idempotent
3873
';
3874

    
3875

    
3876
--
3877
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3878
--
3879

    
3880
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3881
    LANGUAGE plpgsql STRICT
3882
    AS $_$
3883
DECLARE
3884
	row_ util.map;
3885
BEGIN
3886
	-- rename any metadata cols rather than re-adding them with new names
3887
	BEGIN
3888
		PERFORM util.set_col_names(table_, names);
3889
	EXCEPTION
3890
		WHEN array_subscript_error THEN -- selective suppress
3891
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3892
				-- metadata cols not yet added
3893
			ELSE RAISE;
3894
			END IF;
3895
	END;
3896
	
3897
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3898
	LOOP
3899
		PERFORM util.mk_const_col((table_, row_."to"),
3900
			substring(row_."from" from 2));
3901
	END LOOP;
3902
	
3903
	PERFORM util.set_col_names(table_, names);
3904
END;
3905
$_$;
3906

    
3907

    
3908
--
3909
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3910
--
3911

    
3912
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3913
idempotent.
3914
the metadata mappings must be *last* in the names table.
3915
';
3916

    
3917

    
3918
--
3919
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3920
--
3921

    
3922
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3923
    LANGUAGE sql
3924
    AS $_$
3925
SELECT util.eval(COALESCE(
3926
$$ALTER TABLE $$||$1||$$
3927
$$||(
3928
	SELECT
3929
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3930
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
3931
, $$)
3932
	FROM
3933
	(
3934
		SELECT
3935
		  quote_ident(col_name) AS col_name_sql
3936
		, util.col_type(($1, col_name)) AS curr_type
3937
		, type AS target_type
3938
		FROM unnest($2)
3939
	) s
3940
	WHERE curr_type != target_type
3941
), ''))
3942
$_$;
3943

    
3944

    
3945
--
3946
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3947
--
3948

    
3949
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3950
idempotent
3951
';
3952

    
3953

    
3954
--
3955
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3956
--
3957

    
3958
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3959
    LANGUAGE sql
3960
    AS $_$
3961
SELECT util.eval(util.mk_set_comment($1, $2))
3962
$_$;
3963

    
3964

    
3965
--
3966
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3967
--
3968

    
3969
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3970
    LANGUAGE sql
3971
    AS $_$
3972
SELECT util.eval(util.mk_set_search_path($1, $2))
3973
$_$;
3974

    
3975

    
3976
--
3977
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3978
--
3979

    
3980
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
3981
    LANGUAGE sql STABLE
3982
    AS $_$
3983
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
3984
||$1||$$ AS
3985
$$||pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
3986
$$||util.mk_set_relation_metadata($1)
3987
$_$;
3988

    
3989

    
3990
--
3991
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3992
--
3993

    
3994
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3995
    LANGUAGE sql STABLE
3996
    AS $_$
3997
SELECT string_agg(cmd, '')
3998
FROM
3999
(
4000
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
4001
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
4002
$$ ELSE '' END) AS cmd
4003
	FROM util.grants_users() f (user_)
4004
) s
4005
$_$;
4006

    
4007

    
4008
--
4009
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
4010
--
4011

    
4012
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
4013
    LANGUAGE sql STABLE
4014
    AS $_$
4015
SELECT oid FROM pg_class
4016
WHERE relkind = ANY($3) AND relname ~ $1
4017
AND util.schema_matches(util.schema(relnamespace), $2)
4018
ORDER BY relname
4019
$_$;
4020

    
4021

    
4022
--
4023
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
4024
--
4025

    
4026
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
4027
    LANGUAGE sql STABLE
4028
    AS $_$
4029
SELECT util.mk_set_comment($1, util.comment($1))
4030
$_$;
4031

    
4032

    
4033
--
4034
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4035
--
4036

    
4037
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
4038
    LANGUAGE sql STABLE
4039
    AS $_$
4040
SELECT oid
4041
FROM pg_type
4042
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
4043
ORDER BY typname
4044
$_$;
4045

    
4046

    
4047
--
4048
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4049
--
4050

    
4051
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
4052
    LANGUAGE sql STABLE
4053
    AS $_$
4054
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
4055
$_$;
4056

    
4057

    
4058
--
4059
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
4060
--
4061

    
4062
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
4063
    LANGUAGE sql IMMUTABLE
4064
    AS $_$
4065
SELECT '^'||util.regexp_quote($1)||'$'
4066
$_$;
4067

    
4068

    
4069
--
4070
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
4071
--
4072

    
4073
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
4074
    LANGUAGE plpgsql STABLE STRICT
4075
    AS $_$
4076
DECLARE
4077
    hstore hstore;
4078
BEGIN
4079
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
4080
        table_||$$))$$ INTO STRICT hstore;
4081
    RETURN hstore;
4082
END;
4083
$_$;
4084

    
4085

    
4086
--
4087
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4088
--
4089

    
4090
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
4091
    LANGUAGE sql STABLE
4092
    AS $_$
4093
SELECT COUNT(*) > 0 FROM pg_constraint
4094
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
4095
$_$;
4096

    
4097

    
4098
--
4099
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4100
--
4101

    
4102
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
4103
gets whether a status flag is set by the presence of a table constraint
4104
';
4105

    
4106

    
4107
--
4108
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4109
--
4110

    
4111
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
4112
    LANGUAGE sql
4113
    AS $_$
4114
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
4115
||quote_ident($2)||$$ CHECK (true)$$)
4116
$_$;
4117

    
4118

    
4119
--
4120
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4121
--
4122

    
4123
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
4124
stores a status flag by the presence of a table constraint.
4125
idempotent.
4126
';
4127

    
4128

    
4129
--
4130
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
4131
--
4132

    
4133
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
4134
    LANGUAGE sql STABLE
4135
    AS $_$
4136
SELECT util.table_flag__get($1, 'nulls_mapped')
4137
$_$;
4138

    
4139

    
4140
--
4141
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4142
--
4143

    
4144
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
4145
gets whether a table''s NULL-equivalent strings have been replaced with NULL
4146
';
4147

    
4148

    
4149
--
4150
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
4151
--
4152

    
4153
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
4154
    LANGUAGE sql
4155
    AS $_$
4156
SELECT util.table_flag__set($1, 'nulls_mapped')
4157
$_$;
4158

    
4159

    
4160
--
4161
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4162
--
4163

    
4164
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
4165
sets that a table''s NULL-equivalent strings have been replaced with NULL.
4166
idempotent.
4167
';
4168

    
4169

    
4170
--
4171
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
4172
--
4173

    
4174
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
4175
    LANGUAGE sql
4176
    AS $_$
4177
-- save data before truncating main table
4178
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
4179

    
4180
-- repopulate main table w/ copies column
4181
SELECT util.truncate($1);
4182
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
4183
SELECT util.populate_table($1, $$
4184
SELECT (table_).*, copies
4185
FROM (
4186
	SELECT table_, COUNT(*) AS copies
4187
	FROM pg_temp.__copy table_
4188
	GROUP BY table_
4189
) s
4190
$$);
4191

    
4192
-- delete temp table so it doesn't stay around until end of connection
4193
SELECT util.drop_table('pg_temp.__copy');
4194
$_$;
4195

    
4196

    
4197
--
4198
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
4199
--
4200

    
4201
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
4202
    LANGUAGE plpgsql STRICT
4203
    AS $_$
4204
DECLARE
4205
    row record;
4206
BEGIN
4207
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
4208
    LOOP
4209
        IF row.global_name != row.name THEN
4210
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
4211
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
4212
        END IF;
4213
    END LOOP;
4214
END;
4215
$_$;
4216

    
4217

    
4218
--
4219
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4220
--
4221

    
4222
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
4223
idempotent
4224
';
4225

    
4226

    
4227
--
4228
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4229
--
4230

    
4231
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
4232
    LANGUAGE sql
4233
    AS $_$
4234
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
4235
SELECT NULL::void; -- don't fold away functions called in previous query
4236
$_$;
4237

    
4238

    
4239
--
4240
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
4241
--
4242

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

    
4246
by default, cascadingly drops dependent columns so that they don''t prevent
4247
trim() from succeeding. note that this requires the dependent columns to then be
4248
manually re-created.
4249

    
4250
idempotent
4251
';
4252

    
4253

    
4254
--
4255
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4256
--
4257

    
4258
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4259
    LANGUAGE plpgsql STRICT
4260
    AS $_$
4261
BEGIN
4262
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4263
END;
4264
$_$;
4265

    
4266

    
4267
--
4268
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4269
--
4270

    
4271
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4272
idempotent
4273
';
4274

    
4275

    
4276
--
4277
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4278
--
4279

    
4280
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4281
    LANGUAGE sql IMMUTABLE
4282
    AS $_$
4283
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4284
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4285
$_$;
4286

    
4287

    
4288
--
4289
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4290
--
4291

    
4292
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4293
    LANGUAGE plpgsql IMMUTABLE
4294
    AS $$
4295
BEGIN
4296
	/* need explicit cast because some types not implicitly-castable, and also
4297
	to make the cast happen inside the try block. (*implicit* casts to the
4298
	return type happen at the end of the function, outside any block.) */
4299
	RETURN util.cast(value, ret_type_null);
4300
EXCEPTION
4301
WHEN   data_exception
4302
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
4303
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
4304
	THEN
4305
	PERFORM util.raise('WARNING', SQLERRM);
4306
	RETURN NULL;
4307
END;
4308
$$;
4309

    
4310

    
4311
--
4312
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4313
--
4314

    
4315
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4316
ret_type_null: NULL::ret_type
4317
';
4318

    
4319

    
4320
--
4321
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4322
--
4323

    
4324
CREATE FUNCTION try_create(sql text) RETURNS void
4325
    LANGUAGE plpgsql STRICT
4326
    AS $$
4327
BEGIN
4328
	PERFORM util.eval(sql);
4329
EXCEPTION
4330
WHEN   not_null_violation
4331
		/* trying to add NOT NULL column to parent table, which cascades to
4332
		child table whose values for the new column will be NULL */
4333
	OR wrong_object_type -- trying to alter a view's columns
4334
	OR undefined_column
4335
	OR duplicate_column
4336
THEN NULL;
4337
WHEN datatype_mismatch THEN
4338
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4339
	ELSE RAISE; -- rethrow
4340
	END IF;
4341
END;
4342
$$;
4343

    
4344

    
4345
--
4346
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4347
--
4348

    
4349
COMMENT ON FUNCTION try_create(sql text) IS '
4350
idempotent
4351
';
4352

    
4353

    
4354
--
4355
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4356
--
4357

    
4358
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4359
    LANGUAGE sql
4360
    AS $_$
4361
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4362
$_$;
4363

    
4364

    
4365
--
4366
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4367
--
4368

    
4369
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4370
idempotent
4371
';
4372

    
4373

    
4374
--
4375
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4376
--
4377

    
4378
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4379
    LANGUAGE sql IMMUTABLE
4380
    AS $_$
4381
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4382
$_$;
4383

    
4384

    
4385
--
4386
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4387
--
4388

    
4389
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4390
a type''s NOT NULL qualifier
4391
';
4392

    
4393

    
4394
--
4395
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4396
--
4397

    
4398
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4399
    LANGUAGE sql STABLE
4400
    AS $_$
4401
SELECT (attname::text, atttypid)::util.col_cast
4402
FROM pg_attribute
4403
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4404
ORDER BY attnum
4405
$_$;
4406

    
4407

    
4408
--
4409
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4410
--
4411

    
4412
CREATE FUNCTION typeof(value anyelement) RETURNS text
4413
    LANGUAGE sql IMMUTABLE
4414
    AS $_$
4415
SELECT util.qual_name(pg_typeof($1))
4416
$_$;
4417

    
4418

    
4419
--
4420
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4421
--
4422

    
4423
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4424
    LANGUAGE plpgsql STABLE
4425
    AS $_$
4426
DECLARE
4427
    type regtype;
4428
BEGIN
4429
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4430
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4431
    RETURN type;
4432
END;
4433
$_$;
4434

    
4435

    
4436
--
4437
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4438
--
4439

    
4440
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4441
    LANGUAGE sql
4442
    AS $_$
4443
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4444
$_$;
4445

    
4446

    
4447
--
4448
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4449
--
4450

    
4451
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4452
auto-appends util to the search_path to enable use of util operators
4453
';
4454

    
4455

    
4456
--
4457
-- Name: view_def_to_orig(text); Type: FUNCTION; Schema: util; Owner: -
4458
--
4459

    
4460
CREATE FUNCTION view_def_to_orig(view_def text) RETURNS text
4461
    LANGUAGE sql IMMUTABLE
4462
    AS $_$
4463
SELECT
4464
regexp_replace(
4465
regexp_replace(
4466
$1
4467
,
4468
/* unexpand expanded * expressions. any list of 6+ cols from the same table is
4469
treated as a * expression. */
4470
'((?:"[^"\s]+"|\w+)\.)(?:"[^"\s]+"|\w+)'||
4471
	/* 1st col, which lacks separator before.
4472
	*note*: can't prepend \y because it considers only \w chars, not " */
4473
'(,[[:blank:]]*
4474
[[:blank:]]*)\1(?:"[^"\s]+"|\w+)'|| -- 2nd col, which has separator before
4475
'(?:\2\1(?:"[^"\s]+"|\w+)){4,}', -- later cols, w/ same table name and separator
4476
'\1*'/*prefix w/ table*/,
4477
'g')
4478
,
4479
/* merge .* expressions resulting from a SELECT * of a join. any list of
4480
multiple .* expressions is treated as a SELECT * . */
4481
'(?:"[^"\s]+"|\w+)\.\*'||
4482
	/* 1st table, which lacks separator before.
4483
	*note*: can't prepend \y because it considers only \w chars, not " */
4484
'(,[[:blank:]]*
4485
[[:blank:]]*)(?:"[^"\s]+"|\w+)\.\*'|| -- 2nd table, which has separator before
4486
'(?:\1(?:"[^"\s]+"|\w+)\.\*)*', -- later tables, w/ same separator
4487
'*',
4488
'g')
4489
$_$;
4490

    
4491

    
4492
--
4493
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4494
--
4495

    
4496
CREATE AGGREGATE all_same(anyelement) (
4497
    SFUNC = all_same_transform,
4498
    STYPE = anyarray,
4499
    FINALFUNC = all_same_final
4500
);
4501

    
4502

    
4503
--
4504
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4505
--
4506

    
4507
COMMENT ON AGGREGATE all_same(anyelement) IS '
4508
includes NULLs in comparison
4509
';
4510

    
4511

    
4512
--
4513
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4514
--
4515

    
4516
CREATE AGGREGATE join_strs(text, text) (
4517
    SFUNC = join_strs_transform,
4518
    STYPE = text
4519
);
4520

    
4521

    
4522
--
4523
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4524
--
4525

    
4526
CREATE OPERATOR %== (
4527
    PROCEDURE = keys_eq,
4528
    LEFTARG = anyelement,
4529
    RIGHTARG = anyelement
4530
);
4531

    
4532

    
4533
--
4534
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4535
--
4536

    
4537
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4538
returns whether the map-keys of the compared values are the same
4539
(mnemonic: % is the Perl symbol for a hash map)
4540

    
4541
should be overridden for types that store both keys and values
4542

    
4543
used in a FULL JOIN to select which columns to join on
4544
';
4545

    
4546

    
4547
--
4548
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4549
--
4550

    
4551
CREATE OPERATOR -> (
4552
    PROCEDURE = map_get,
4553
    LEFTARG = regclass,
4554
    RIGHTARG = text
4555
);
4556

    
4557

    
4558
--
4559
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4560
--
4561

    
4562
CREATE OPERATOR => (
4563
    PROCEDURE = hstore,
4564
    LEFTARG = text[],
4565
    RIGHTARG = text
4566
);
4567

    
4568

    
4569
--
4570
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4571
--
4572

    
4573
COMMENT ON OPERATOR => (text[], text) IS '
4574
usage: array[''key1'', ...]::text[] => ''value''
4575
';
4576

    
4577

    
4578
--
4579
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4580
--
4581

    
4582
CREATE OPERATOR ?*>= (
4583
    PROCEDURE = is_populated_more_often_than,
4584
    LEFTARG = anyelement,
4585
    RIGHTARG = anyelement
4586
);
4587

    
4588

    
4589
--
4590
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4591
--
4592

    
4593
CREATE OPERATOR ?>= (
4594
    PROCEDURE = is_more_complete_than,
4595
    LEFTARG = anyelement,
4596
    RIGHTARG = anyelement
4597
);
4598

    
4599

    
4600
--
4601
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4602
--
4603

    
4604
CREATE OPERATOR ||% (
4605
    PROCEDURE = concat_esc,
4606
    LEFTARG = text,
4607
    RIGHTARG = text
4608
);
4609

    
4610

    
4611
--
4612
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4613
--
4614

    
4615
COMMENT ON OPERATOR ||% (text, text) IS '
4616
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4617
';
4618

    
4619

    
4620
--
4621
-- Name: ~; Type: OPERATOR; Schema: util; Owner: -
4622
--
4623

    
4624
CREATE OPERATOR ~ (
4625
    PROCEDURE = range,
4626
    LEFTARG = numeric,
4627
    RIGHTARG = numeric
4628
);
4629

    
4630

    
4631
--
4632
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4633
--
4634

    
4635
CREATE TABLE map (
4636
    "from" text NOT NULL,
4637
    "to" text,
4638
    filter text,
4639
    notes text
4640
);
4641

    
4642

    
4643
--
4644
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4645
--
4646

    
4647

    
4648

    
4649
--
4650
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4651
--
4652

    
4653

    
4654

    
4655
--
4656
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4657
--
4658

    
4659
ALTER TABLE ONLY map
4660
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4661

    
4662

    
4663
--
4664
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4665
--
4666

    
4667
ALTER TABLE ONLY map
4668
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4669

    
4670

    
4671
--
4672
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4673
--
4674

    
4675
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4676

    
4677

    
4678
--
4679
-- PostgreSQL database dump complete
4680
--
4681

    
(21-21/31)