Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

    
23
COMMENT ON SCHEMA util IS '
24
IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.
25

    
26
NOTE: SQL-language functions should never be declared STRICT, because this prevents them from being inlined. inlining can create a significant speed improvement (7x+), by avoiding function calls and enabling additional constant folding. avoiding use of STRICT also makes functions *much* easier to troubleshoot, because they won''t mysteriously do nothing if called with only NULL arguments, even when you have added debug-print statements.
27
';
28

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

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

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

    
84

    
85
--
86
-- Name: FUNCTION "%=="(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
87
--
88

    
89
COMMENT ON FUNCTION "%=="(left_ anyelement, right_ anyelement) IS '
90
needs to be declared STABLE instead of IMMUTABLE because it depends on the search_path (as described at http://vegpath.org/links/#PostgreSQL:%20Documentation:%209.3:%20Function%20Volatility%20Categories%20**)
91
';
92

    
93

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

    
98
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
99
    LANGUAGE sql IMMUTABLE
100
    AS $_$
101
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
102
$_$;
103

    
104

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

    
109
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
110
    LANGUAGE sql IMMUTABLE
111
    AS $_$
112
SELECT bool_and(value)
113
FROM
114
(VALUES
115
      ($1)
116
    , ($2)
117
    , ($3)
118
    , ($4)
119
    , ($5)
120
)
121
AS v (value)
122
$_$;
123

    
124

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

    
129
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
130
_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.
131
';
132

    
133

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

    
138
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
139
    LANGUAGE sql IMMUTABLE
140
    AS $_$
141
SELECT avg(value)
142
FROM
143
(VALUES
144
      ($1)
145
    , ($2)
146
    , ($3)
147
    , ($4)
148
    , ($5)
149
)
150
AS v (value)
151
$_$;
152

    
153

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

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

    
172

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

    
177
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
178
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
181
FROM
182
(VALUES
183
      ($1)
184
    , ($2/60)
185
    , ($3/60/60)
186
)
187
AS v (value)
188
$_$;
189

    
190

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

    
195
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
196
    LANGUAGE sql IMMUTABLE
197
    AS $_$
198
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
199
$_$;
200

    
201

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

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

    
212

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

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

    
225

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

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

    
236

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

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

    
247

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

    
252
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
253
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
256
$_$;
257

    
258

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

    
263
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
264
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
267
$_$;
268

    
269

    
270
--
271
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
272
--
273

    
274
CREATE FUNCTION _label(label text, value text) RETURNS text
275
    LANGUAGE sql IMMUTABLE
276
    AS $_$
277
SELECT coalesce($1 || ': ', '') || $2
278
$_$;
279

    
280

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

    
285
CREATE FUNCTION _lowercase(value text) RETURNS text
286
    LANGUAGE sql IMMUTABLE
287
    AS $_$
288
SELECT lower($1)
289
$_$;
290

    
291

    
292
--
293
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
294
--
295

    
296
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
297
    LANGUAGE plpgsql IMMUTABLE STRICT
298
    AS $$
299
DECLARE
300
    result value%TYPE := util._map(map, value::text)::unknown;
301
BEGIN
302
    RETURN result;
303
END;
304
$$;
305

    
306

    
307
--
308
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
309
--
310

    
311
CREATE FUNCTION _map(map hstore, value text) RETURNS text
312
    LANGUAGE plpgsql IMMUTABLE STRICT
313
    AS $$
314
DECLARE
315
    match text := map -> value;
316
BEGIN
317
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
318
        match := map -> '*'; -- use default entry
319
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
320
        END IF;
321
    END IF;
322
    
323
    -- Interpret result
324
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
325
    ELSIF match = '*' THEN RETURN value;
326
    ELSE RETURN match;
327
    END IF;
328
END;
329
$$;
330

    
331

    
332
--
333
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
334
--
335

    
336
CREATE FUNCTION _max("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
337
    LANGUAGE sql IMMUTABLE
338
    AS $_$
339
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
340
$_$;
341

    
342

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

    
347
CREATE FUNCTION _merge("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
348
    LANGUAGE sql IMMUTABLE
349
    AS $_$
350
SELECT util.join_strs(value, '; ')
351
FROM
352
(
353
    SELECT *
354
    FROM
355
    (
356
        SELECT
357
        DISTINCT ON (value)
358
        *
359
        FROM
360
        (VALUES
361
              (1, $1)
362
            , (2, $2)
363
            , (3, $3)
364
            , (4, $4)
365
            , (5, $5)
366
            , (6, $6)
367
            , (7, $7)
368
            , (8, $8)
369
            , (9, $9)
370
            , (10, $10)
371
        )
372
        AS v (sort_order, value)
373
        WHERE value IS NOT NULL
374
    )
375
    AS v
376
    ORDER BY sort_order
377
)
378
AS v
379
$_$;
380

    
381

    
382
--
383
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
384
--
385

    
386
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
387
    LANGUAGE sql IMMUTABLE
388
    AS $_$
389
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
390
$_$;
391

    
392

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

    
397
CREATE FUNCTION _merge_words("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
398
    LANGUAGE sql IMMUTABLE
399
    AS $_$
400
SELECT util.join_strs(value, ' ')
401
FROM
402
(
403
    SELECT *
404
    FROM
405
    (
406
        SELECT
407
        DISTINCT ON (value)
408
        *
409
        FROM
410
        (VALUES
411
              (1, $1)
412
            , (2, $2)
413
            , (3, $3)
414
            , (4, $4)
415
            , (5, $5)
416
            , (6, $6)
417
            , (7, $7)
418
            , (8, $8)
419
            , (9, $9)
420
            , (10, $10)
421
        )
422
        AS v (sort_order, value)
423
        WHERE value IS NOT NULL
424
    )
425
    AS v
426
    ORDER BY sort_order
427
)
428
AS v
429
$_$;
430

    
431

    
432
--
433
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
434
--
435

    
436
CREATE FUNCTION _min("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
437
    LANGUAGE sql IMMUTABLE
438
    AS $_$
439
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
440
$_$;
441

    
442

    
443
--
444
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
445
--
446

    
447
CREATE FUNCTION _not(value boolean) RETURNS boolean
448
    LANGUAGE sql IMMUTABLE
449
    AS $_$
450
SELECT NOT $1
451
$_$;
452

    
453

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

    
458
CREATE FUNCTION _now() RETURNS timestamp with time zone
459
    LANGUAGE sql STABLE
460
    AS $$
461
SELECT now()
462
$$;
463

    
464

    
465
--
466
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
467
--
468

    
469
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
470
    LANGUAGE sql IMMUTABLE
471
    AS $_$
472
SELECT util."_nullIf"($1, $2, $3::util.datatype)
473
$_$;
474

    
475

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

    
480
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
481
    LANGUAGE plpgsql IMMUTABLE
482
    AS $$
483
DECLARE
484
    type util.datatype NOT NULL := type; -- add NOT NULL
485
BEGIN
486
    IF type = 'str' THEN RETURN nullif(value::text, "null");
487
    -- Invalid value is ignored, but invalid null value generates error
488
    ELSIF type = 'float' THEN
489
        DECLARE
490
            -- Outside the try block so that invalid null value generates error
491
            "null" double precision := "null"::double precision;
492
        BEGIN
493
            RETURN nullif(value::double precision, "null");
494
        EXCEPTION
495
            WHEN data_exception THEN RETURN value; -- ignore invalid value
496
        END;
497
    END IF;
498
END;
499
$$;
500

    
501

    
502
--
503
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
504
--
505

    
506
CREATE FUNCTION _or("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
507
    LANGUAGE sql IMMUTABLE
508
    AS $_$
509
SELECT bool_or(value)
510
FROM
511
(VALUES
512
      ($1)
513
    , ($2)
514
    , ($3)
515
    , ($4)
516
    , ($5)
517
)
518
AS v (value)
519
$_$;
520

    
521

    
522
--
523
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
524
--
525

    
526
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
527
_or() ignores NULL values, while OR combines them with the other values to potentially convert false to NULL. OR should be used with required fields, and _or() with optional fields.
528
';
529

    
530

    
531
--
532
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
533
--
534

    
535
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
536
    LANGUAGE sql IMMUTABLE
537
    AS $_$
538
SELECT $2 - $1
539
$_$;
540

    
541

    
542
--
543
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
544
--
545

    
546
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
547
    LANGUAGE sql IMMUTABLE
548
    AS $_$
549
SELECT regexp_split_to_table($1, $2)
550
$_$;
551

    
552

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

    
557
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
558
    LANGUAGE sql STABLE
559
    AS $_$
560
SELECT util.derived_cols($1, $2)
561
UNION
562
SELECT util.eval2set($$
563
SELECT col
564
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
565
JOIN $$||$2||$$ ON "to" = col
566
WHERE "from" LIKE ':%'
567
$$, NULL::text)
568
$_$;
569

    
570

    
571
--
572
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
573
--
574

    
575
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
576
gets table_''s added columns (all the columns not in the original data)
577
';
578

    
579

    
580
--
581
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
582
--
583

    
584
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
585
    LANGUAGE sql IMMUTABLE
586
    AS $_$
587
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
588
$_$;
589

    
590

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

    
595
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
596
    LANGUAGE plpgsql IMMUTABLE
597
    AS $$
598
DECLARE
599
	value_cmp         state%TYPE = ARRAY[value];
600
	state             state%TYPE = COALESCE(state, value_cmp);
601
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
602
BEGIN
603
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
604
END;
605
$$;
606

    
607

    
608
--
609
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
610
--
611

    
612
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
613
    LANGUAGE sql
614
    AS $_$
615
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
616
$_$;
617

    
618

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

    
623
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
624
    LANGUAGE sql
625
    AS $_$
626
SELECT util.set_comment($1, concat(util.comment($1), $2))
627
$_$;
628

    
629

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

    
634
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
635
comment: must start and end with a newline
636
';
637

    
638

    
639
--
640
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
641
--
642

    
643
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
644
    LANGUAGE sql IMMUTABLE
645
    AS $_$
646
SELECT pg_catalog.array_fill($1, ARRAY[$2])
647
$_$;
648

    
649

    
650
--
651
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
652
--
653

    
654
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
655
    LANGUAGE sql IMMUTABLE
656
    AS $_$
657
SELECT util.array_length($1, 1)
658
$_$;
659

    
660

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

    
665
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
666
    LANGUAGE sql IMMUTABLE
667
    AS $_$
668
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
669
$_$;
670

    
671

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

    
676
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
677
returns 0 instead of NULL for empty arrays
678
';
679

    
680

    
681
--
682
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
683
--
684

    
685
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
686
    LANGUAGE sql STABLE
687
    AS $_$
688
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
689
$_$;
690

    
691

    
692
--
693
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
694
--
695

    
696
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
697
    LANGUAGE plpgsql STRICT
698
    AS $_$
699
BEGIN
700
    -- not yet clustered (ARRAY[] compares NULLs literally)
701
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
702
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
703
    END IF;
704
END;
705
$_$;
706

    
707

    
708
--
709
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
710
--
711

    
712
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
713
idempotent
714
';
715

    
716

    
717
--
718
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
719
--
720

    
721
CREATE FUNCTION col__min(col col_ref) RETURNS integer
722
    LANGUAGE sql STABLE
723
    AS $_$
724
SELECT util.eval2val($$
725
SELECT $$||quote_ident($1.name)||$$
726
FROM $$||$1.table_||$$
727
ORDER BY $$||quote_ident($1.name)||$$ ASC
728
LIMIT 1
729
$$, NULL::integer)
730
$_$;
731

    
732

    
733
--
734
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
735
--
736

    
737
CREATE FUNCTION col_comment(col col_ref) RETURNS text
738
    LANGUAGE plpgsql STABLE STRICT
739
    AS $$
740
DECLARE
741
	comment text;
742
BEGIN
743
	SELECT description
744
	FROM pg_attribute
745
	LEFT JOIN pg_description ON objoid = attrelid
746
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
747
	WHERE attrelid = col.table_ AND attname = col.name
748
	INTO STRICT comment
749
	;
750
	RETURN comment;
751
EXCEPTION
752
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
753
END;
754
$$;
755

    
756

    
757
--
758
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
759
--
760

    
761
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
762
    LANGUAGE plpgsql STABLE STRICT
763
    AS $$
764
DECLARE
765
	default_sql text;
766
BEGIN
767
	SELECT adsrc
768
	FROM pg_attribute
769
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
770
	WHERE attrelid = col.table_ AND attname = col.name
771
	INTO STRICT default_sql
772
	;
773
	RETURN default_sql;
774
EXCEPTION
775
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
776
END;
777
$$;
778

    
779

    
780
--
781
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
782
--
783

    
784
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
785
    LANGUAGE sql STABLE
786
    AS $_$
787
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
788
$_$;
789

    
790

    
791
--
792
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
793
--
794

    
795
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
796
ret_type_null: NULL::ret_type
797
';
798

    
799

    
800
--
801
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
802
--
803

    
804
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
805
    LANGUAGE plpgsql STRICT
806
    AS $$
807
BEGIN
808
    PERFORM util.col_type(col);
809
    RETURN true;
810
EXCEPTION
811
    WHEN undefined_column THEN RETURN false;
812
END;
813
$$;
814

    
815

    
816
--
817
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
818
--
819

    
820
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
821
    LANGUAGE plpgsql STABLE STRICT
822
    AS $$
823
DECLARE
824
    prefix text := util.name(type)||'.';
825
BEGIN
826
    RETURN QUERY
827
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
828
        FROM util.col_names(type) f (name_);
829
END;
830
$$;
831

    
832

    
833
--
834
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
835
--
836

    
837
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
838
    LANGUAGE sql STABLE
839
    AS $_$
840
SELECT attname::text
841
FROM pg_attribute
842
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
843
ORDER BY attnum
844
$_$;
845

    
846

    
847
--
848
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
849
--
850

    
851
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
852
    LANGUAGE plpgsql STABLE STRICT
853
    AS $_$
854
BEGIN
855
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
856
END;
857
$_$;
858

    
859

    
860
--
861
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
862
--
863

    
864
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
865
    LANGUAGE plpgsql STABLE STRICT
866
    AS $$
867
DECLARE
868
    type regtype;
869
BEGIN
870
    SELECT atttypid FROM pg_attribute
871
    WHERE attrelid = col.table_ AND attname = col.name
872
    INTO STRICT type
873
    ;
874
    RETURN type;
875
EXCEPTION
876
    WHEN no_data_found THEN
877
        RAISE undefined_column USING MESSAGE =
878
            concat('undefined column: ', col.name);
879
END;
880
$$;
881

    
882

    
883
--
884
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
885
--
886

    
887
CREATE FUNCTION comment(element oid) RETURNS text
888
    LANGUAGE sql STABLE
889
    AS $_$
890
SELECT description FROM pg_description WHERE objoid = $1
891
$_$;
892

    
893

    
894
--
895
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
896
--
897

    
898
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
899
    LANGUAGE sql IMMUTABLE
900
    AS $_$
901
SELECT util.esc_name__append($2, $1)
902
$_$;
903

    
904

    
905
--
906
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
907
--
908

    
909
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
910
    LANGUAGE sql IMMUTABLE
911
    AS $_$
912
SELECT position($1 in $2) > 0 /*1-based offset*/
913
$_$;
914

    
915

    
916
--
917
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
918
--
919

    
920
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
921
    LANGUAGE sql
922
    AS $_$
923
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
924
$_$;
925

    
926

    
927
--
928
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
929
--
930

    
931
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
932
    LANGUAGE plpgsql STRICT
933
    AS $$
934
BEGIN
935
    PERFORM util.eval(sql);
936
EXCEPTION
937
    WHEN duplicate_table  THEN NULL;
938
    WHEN duplicate_object THEN NULL; -- e.g. constraint
939
    WHEN duplicate_column THEN NULL;
940
    WHEN invalid_table_definition THEN
941
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
942
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
943
        END IF;
944
END;
945
$$;
946

    
947

    
948
--
949
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
950
--
951

    
952
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
953
idempotent
954
';
955

    
956

    
957
--
958
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
959
--
960

    
961
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
962
    LANGUAGE sql IMMUTABLE
963
    AS $$
964
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
965
$$;
966

    
967

    
968
--
969
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
970
--
971

    
972
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
973
    LANGUAGE sql IMMUTABLE
974
    AS $_$
975
SELECT util.raise_notice('returns: '
976
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
977
SELECT $1;
978
$_$;
979

    
980

    
981
--
982
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
983
--
984

    
985
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
986
    LANGUAGE sql IMMUTABLE
987
    AS $_$
988
/* newline before so the query starts at the beginning of the line.
989
newline after to visually separate queries from one another. */
990
SELECT util.raise_notice($$
991
$$||util.runnable_sql($1)||$$
992
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
993
$_$;
994

    
995

    
996
--
997
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
998
--
999

    
1000
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1001
    LANGUAGE sql STABLE
1002
    AS $_$
1003
SELECT util.eval2set($$
1004
SELECT col
1005
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1006
LEFT JOIN $$||$2||$$ ON "to" = col
1007
WHERE "from" IS NULL
1008
$$, NULL::text)
1009
$_$;
1010

    
1011

    
1012
--
1013
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1014
--
1015

    
1016
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1017
gets table_''s derived columns (all the columns not in the names table)
1018
';
1019

    
1020

    
1021
--
1022
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1023
--
1024

    
1025
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1026
    LANGUAGE sql
1027
    AS $_$
1028
SELECT * FROM util.diff($1::text, $2::text, $3,
1029
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1030
$_$;
1031

    
1032

    
1033
--
1034
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1035
--
1036

    
1037
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1038
col_type_null (*required*): NULL::shared_base_type
1039
usage:
1040
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1041
';
1042

    
1043

    
1044
--
1045
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1046
--
1047

    
1048
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
1049
    LANGUAGE plpgsql
1050
    SET search_path TO pg_temp
1051
    AS $_$
1052
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1053
changes of search_path (schema elements are bound at inline time rather than
1054
runtime) */
1055
/* function option search_path is needed to limit the effects of
1056
`SET LOCAL search_path` to the current function */
1057
BEGIN
1058
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1059
	
1060
	RETURN QUERY
1061
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2, $4,
1062
$$/* need to explicitly cast each side to the return type because this does not
1063
happen automatically even when an implicit cast is available */
1064
  left_::$$||util.typeof($3)||$$
1065
, right_::$$||util.typeof($3)
1066
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1067
the *same* base type, *even though* this is optional when using a custom %== */
1068
,$$ left_::$$||util.typeof($3)||$$
1069
%== right_::$$||util.typeof($3)||$$
1070
	-- refer to EXPLAIN output for expansion of %==$$
1071
), $3)
1072
	;
1073
END;
1074
$_$;
1075

    
1076

    
1077
--
1078
-- 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: -
1079
--
1080

    
1081
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1082
col_type_null (*required*): NULL::col_type
1083
single_row: whether the tables consist of a single row, which should be
1084
	displayed side-by-side
1085

    
1086
to match up rows using a subset of the columns, create a custom keys() function
1087
which returns this subset as a record:
1088
-- note that OUT parameters for the returned fields are *not* needed
1089
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1090
  RETURNS record AS
1091
$BODY$
1092
SELECT ($1.key_field_0, $1.key_field_1)
1093
$BODY$
1094
  LANGUAGE sql IMMUTABLE
1095
  COST 100;
1096

    
1097

    
1098
to run EXPLAIN on the FULL JOIN query:
1099
# run this function
1100
# look for a NOTICE containing the expanded query that it ran
1101
# run EXPLAIN on this expanded query
1102
';
1103

    
1104

    
1105
--
1106
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1107
--
1108

    
1109
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1110
    LANGUAGE sql
1111
    AS $_$
1112
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1113
$_$;
1114

    
1115

    
1116
--
1117
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1118
--
1119

    
1120
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1121
idempotent
1122
';
1123

    
1124

    
1125
--
1126
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1127
--
1128

    
1129
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1130
    LANGUAGE sql
1131
    AS $_$
1132
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1133
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1134
$_$;
1135

    
1136

    
1137
--
1138
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1139
--
1140

    
1141
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1142
idempotent
1143
';
1144

    
1145

    
1146
--
1147
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1148
--
1149

    
1150
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1151
    LANGUAGE sql
1152
    AS $_$
1153
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1154
included in the debug SQL */
1155
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1156
$_$;
1157

    
1158

    
1159
--
1160
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1161
--
1162

    
1163
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1164
    LANGUAGE sql
1165
    AS $_$
1166
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1167
||util._if($3, $$ CASCADE$$, ''::text))
1168
$_$;
1169

    
1170

    
1171
--
1172
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1173
--
1174

    
1175
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1176
idempotent
1177
';
1178

    
1179

    
1180
--
1181
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1182
--
1183

    
1184
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1185
    LANGUAGE sql
1186
    AS $_$
1187
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1188
$_$;
1189

    
1190

    
1191
--
1192
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1193
--
1194

    
1195
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1196
    LANGUAGE sql
1197
    AS $_$
1198
SELECT util.drop_relation(relation, $3)
1199
FROM util.show_relations_like($1, $2) relation
1200
;
1201
SELECT NULL::void; -- don't fold away functions called in previous query
1202
$_$;
1203

    
1204

    
1205
--
1206
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1207
--
1208

    
1209
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1210
    LANGUAGE sql
1211
    AS $_$
1212
SELECT util.drop_relation('TABLE', $1, $2)
1213
$_$;
1214

    
1215

    
1216
--
1217
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1218
--
1219

    
1220
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1221
idempotent
1222
';
1223

    
1224

    
1225
--
1226
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1227
--
1228

    
1229
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1230
    LANGUAGE sql
1231
    AS $_$
1232
SELECT util.drop_relation('VIEW', $1, $2)
1233
$_$;
1234

    
1235

    
1236
--
1237
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1238
--
1239

    
1240
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1241
idempotent
1242
';
1243

    
1244

    
1245
--
1246
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1247
--
1248

    
1249
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1250
    LANGUAGE sql IMMUTABLE
1251
    AS $_$
1252
SELECT util.array_fill($1, 0)
1253
$_$;
1254

    
1255

    
1256
--
1257
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1258
--
1259

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

    
1264

    
1265
--
1266
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1267
--
1268

    
1269
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1270
    LANGUAGE sql IMMUTABLE
1271
    AS $_$
1272
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1273
$_$;
1274

    
1275

    
1276
--
1277
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1278
--
1279

    
1280
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1281
    LANGUAGE sql IMMUTABLE
1282
    AS $_$
1283
SELECT regexp_replace($2, '("?)$', $1||'\1')
1284
$_$;
1285

    
1286

    
1287
--
1288
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1289
--
1290

    
1291
CREATE FUNCTION eval(sql text) RETURNS void
1292
    LANGUAGE plpgsql STRICT
1293
    AS $$
1294
BEGIN
1295
	PERFORM util.debug_print_sql(sql);
1296
	EXECUTE sql;
1297
END;
1298
$$;
1299

    
1300

    
1301
--
1302
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1303
--
1304

    
1305
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1306
    LANGUAGE plpgsql
1307
    AS $$
1308
BEGIN
1309
	PERFORM util.debug_print_sql(sql);
1310
	RETURN QUERY EXECUTE sql;
1311
END;
1312
$$;
1313

    
1314

    
1315
--
1316
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1317
--
1318

    
1319
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1320
col_type_null (*required*): NULL::col_type
1321
';
1322

    
1323

    
1324
--
1325
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1326
--
1327

    
1328
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1329
    LANGUAGE plpgsql
1330
    AS $$
1331
BEGIN
1332
	PERFORM util.debug_print_sql(sql);
1333
	RETURN QUERY EXECUTE sql;
1334
END;
1335
$$;
1336

    
1337

    
1338
--
1339
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1340
--
1341

    
1342
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1343
    LANGUAGE plpgsql
1344
    AS $$
1345
BEGIN
1346
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1347
	RETURN QUERY EXECUTE sql;
1348
END;
1349
$$;
1350

    
1351

    
1352
--
1353
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1354
--
1355

    
1356
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1357
    LANGUAGE plpgsql
1358
    AS $$
1359
DECLARE
1360
	ret_val ret_type_null%TYPE;
1361
BEGIN
1362
	PERFORM util.debug_print_sql(sql);
1363
	EXECUTE sql INTO STRICT ret_val;
1364
	RETURN ret_val;
1365
END;
1366
$$;
1367

    
1368

    
1369
--
1370
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1371
--
1372

    
1373
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1374
ret_type_null: NULL::ret_type
1375
';
1376

    
1377

    
1378
--
1379
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1380
--
1381

    
1382
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1383
    LANGUAGE sql
1384
    AS $_$
1385
SELECT util.eval2val($$SELECT $$||$1, $2)
1386
$_$;
1387

    
1388

    
1389
--
1390
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1391
--
1392

    
1393
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1394
ret_type_null: NULL::ret_type
1395
';
1396

    
1397

    
1398
--
1399
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1400
--
1401

    
1402
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1403
    LANGUAGE sql
1404
    AS $_$
1405
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1406
$_$;
1407

    
1408

    
1409
--
1410
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1411
--
1412

    
1413
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1414
sql: can be NULL, which will be passed through
1415
ret_type_null: NULL::ret_type
1416
';
1417

    
1418

    
1419
--
1420
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1421
--
1422

    
1423
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1424
    LANGUAGE sql STABLE
1425
    AS $_$
1426
SELECT col_name
1427
FROM unnest($2) s (col_name)
1428
WHERE util.col_exists(($1, col_name))
1429
$_$;
1430

    
1431

    
1432
--
1433
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1434
--
1435

    
1436
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1437
    LANGUAGE sql
1438
    AS $_$
1439
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1440
$_$;
1441

    
1442

    
1443
--
1444
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1445
--
1446

    
1447
CREATE FUNCTION explain2notice(sql text) RETURNS void
1448
    LANGUAGE sql
1449
    AS $_$
1450
SELECT util.raise_notice(util.explain2notice_msg($1))
1451
$_$;
1452

    
1453

    
1454
--
1455
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1456
--
1457

    
1458
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1459
    LANGUAGE sql
1460
    AS $_$
1461
-- newline before and after to visually separate it from other debug info
1462
SELECT $$
1463
EXPLAIN:
1464
$$||util.explain2str($1)||$$
1465
$$
1466
$_$;
1467

    
1468

    
1469
--
1470
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1471
--
1472

    
1473
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1474
    LANGUAGE sql
1475
    AS $_$
1476
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1477
$_$;
1478

    
1479

    
1480
--
1481
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1482
--
1483

    
1484
CREATE FUNCTION explain2str(sql text) RETURNS text
1485
    LANGUAGE sql
1486
    AS $_$
1487
SELECT util.join_strs(explain, $$
1488
$$) FROM util.explain($1)
1489
$_$;
1490

    
1491

    
1492
SET default_tablespace = '';
1493

    
1494
SET default_with_oids = false;
1495

    
1496
--
1497
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1498
--
1499

    
1500
CREATE TABLE explain (
1501
    line text NOT NULL
1502
);
1503

    
1504

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

    
1509
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1510
    LANGUAGE sql
1511
    AS $_$
1512
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1513
$$||quote_nullable($1)||$$
1514
)$$)
1515
$_$;
1516

    
1517

    
1518
--
1519
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1520
--
1521

    
1522
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1523
usage:
1524
PERFORM util.explain2table($$
1525
query
1526
$$);
1527
';
1528

    
1529

    
1530
--
1531
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1532
--
1533

    
1534
CREATE FUNCTION first_word(str text) RETURNS text
1535
    LANGUAGE sql IMMUTABLE
1536
    AS $_$
1537
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1538
$_$;
1539

    
1540

    
1541
--
1542
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1543
--
1544

    
1545
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1546
    LANGUAGE sql IMMUTABLE
1547
    AS $_$
1548
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1549
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1550
) END
1551
$_$;
1552

    
1553

    
1554
--
1555
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1556
--
1557

    
1558
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1559
ensures that an array will always have proper non-NULL dimensions
1560
';
1561

    
1562

    
1563
--
1564
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1565
--
1566

    
1567
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1568
    LANGUAGE plpgsql
1569
    AS $_$
1570
DECLARE
1571
	PG_EXCEPTION_DETAIL text;
1572
	recreate_users_cmd text = util.save_drop_views(users);
1573
BEGIN
1574
	PERFORM util.eval(cmd);
1575
	PERFORM util.eval(recreate_users_cmd);
1576
EXCEPTION
1577
WHEN dependent_objects_still_exist THEN
1578
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1579
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1580
	users = array(SELECT * FROM util.regexp_matches_group(
1581
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1582
	IF util.is_empty(users) THEN RAISE; END IF;
1583
	PERFORM util.force_recreate(cmd, users);
1584
END;
1585
$_$;
1586

    
1587

    
1588
--
1589
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1590
--
1591

    
1592
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1593
idempotent
1594

    
1595
users: not necessary to provide this because it will be autopopulated
1596
';
1597

    
1598

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

    
1603
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1604
    LANGUAGE plpgsql STRICT
1605
    AS $_$
1606
DECLARE
1607
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1608
$$||query;
1609
BEGIN
1610
	EXECUTE mk_view;
1611
EXCEPTION
1612
WHEN invalid_table_definition THEN
1613
	IF SQLERRM = 'cannot drop columns from view'
1614
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1615
	THEN
1616
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1617
		EXECUTE mk_view;
1618
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1619
	END IF;
1620
END;
1621
$_$;
1622

    
1623

    
1624
--
1625
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1626
--
1627

    
1628
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1629
idempotent
1630
';
1631

    
1632

    
1633
--
1634
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1635
--
1636

    
1637
CREATE FUNCTION grants_users() RETURNS SETOF text
1638
    LANGUAGE sql IMMUTABLE
1639
    AS $$
1640
VALUES ('bien_read'), ('public_')
1641
$$;
1642

    
1643

    
1644
--
1645
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1646
--
1647

    
1648
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1649
    LANGUAGE sql IMMUTABLE
1650
    AS $_$
1651
SELECT substring($2 for length($1)) = $1
1652
$_$;
1653

    
1654

    
1655
--
1656
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1657
--
1658

    
1659
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1660
    LANGUAGE sql STABLE
1661
    AS $_$
1662
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1663
$_$;
1664

    
1665

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

    
1670
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1671
    LANGUAGE sql IMMUTABLE
1672
    AS $_$
1673
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1674
$_$;
1675

    
1676

    
1677
--
1678
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1679
--
1680

    
1681
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1682
avoids repeating the same value for each key
1683
';
1684

    
1685

    
1686
--
1687
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1688
--
1689

    
1690
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1691
    LANGUAGE sql IMMUTABLE
1692
    AS $_$
1693
SELECT COALESCE($1, $2)
1694
$_$;
1695

    
1696

    
1697
--
1698
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1699
--
1700

    
1701
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1702
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1703
';
1704

    
1705

    
1706
--
1707
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1708
--
1709

    
1710
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1711
    LANGUAGE sql
1712
    AS $_$
1713
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1714
$_$;
1715

    
1716

    
1717
--
1718
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1719
--
1720

    
1721
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1722
    LANGUAGE sql STABLE
1723
    AS $_$
1724
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1725
$_$;
1726

    
1727

    
1728
--
1729
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1730
--
1731

    
1732
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1733
    LANGUAGE sql IMMUTABLE
1734
    AS $_$
1735
SELECT util.array_length($1) = 0
1736
$_$;
1737

    
1738

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

    
1743
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1744
    LANGUAGE sql IMMUTABLE
1745
    AS $_$
1746
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1747
$_$;
1748

    
1749

    
1750
--
1751
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1752
--
1753

    
1754
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1755
    LANGUAGE sql IMMUTABLE
1756
    AS $_$
1757
SELECT upper(util.first_word($1)) = ANY(
1758
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1759
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1760
)
1761
$_$;
1762

    
1763

    
1764
--
1765
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1766
--
1767

    
1768
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1769
    LANGUAGE sql IMMUTABLE
1770
    AS $_$
1771
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1772
$_$;
1773

    
1774

    
1775
--
1776
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1777
--
1778

    
1779
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1780
    LANGUAGE sql IMMUTABLE
1781
    AS $_$
1782
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1783
$_$;
1784

    
1785

    
1786
--
1787
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1788
--
1789

    
1790
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1791
    LANGUAGE sql IMMUTABLE
1792
    AS $_$
1793
SELECT upper(util.first_word($1)) = 'SET'
1794
$_$;
1795

    
1796

    
1797
--
1798
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1799
--
1800

    
1801
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1802
    LANGUAGE sql STABLE
1803
    AS $_$
1804
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1805
$_$;
1806

    
1807

    
1808
--
1809
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1810
--
1811

    
1812
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1813
    LANGUAGE sql STABLE
1814
    AS $_$
1815
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1816
$_$;
1817

    
1818

    
1819
--
1820
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1821
--
1822

    
1823
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1824
    LANGUAGE sql IMMUTABLE STRICT
1825
    AS $_$
1826
SELECT $1 || $3 || $2
1827
$_$;
1828

    
1829

    
1830
--
1831
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1832
--
1833

    
1834
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1835
must be declared STRICT to use the special handling of STRICT aggregating functions
1836
';
1837

    
1838

    
1839
--
1840
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1841
--
1842

    
1843
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1844
    LANGUAGE sql IMMUTABLE
1845
    AS $_$
1846
SELECT $1 -- compare on the entire value
1847
$_$;
1848

    
1849

    
1850
--
1851
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1852
--
1853

    
1854
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1855
    LANGUAGE sql IMMUTABLE
1856
    AS $_$
1857
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1858
$_$;
1859

    
1860

    
1861
--
1862
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1863
--
1864

    
1865
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1866
    LANGUAGE sql IMMUTABLE
1867
    AS $_$
1868
SELECT ltrim($1, $$
1869
$$)
1870
$_$;
1871

    
1872

    
1873
--
1874
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1875
--
1876

    
1877
CREATE FUNCTION map_filter_insert() RETURNS trigger
1878
    LANGUAGE plpgsql
1879
    AS $$
1880
BEGIN
1881
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1882
	RETURN new;
1883
END;
1884
$$;
1885

    
1886

    
1887
--
1888
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1889
--
1890

    
1891
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1892
    LANGUAGE plpgsql STABLE STRICT
1893
    AS $_$
1894
DECLARE
1895
    value text;
1896
BEGIN
1897
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1898
        INTO value USING key;
1899
    RETURN value;
1900
END;
1901
$_$;
1902

    
1903

    
1904
--
1905
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1906
--
1907

    
1908
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1909
    LANGUAGE sql IMMUTABLE
1910
    AS $_$
1911
SELECT util._map(util.nulls_map($1), $2)
1912
$_$;
1913

    
1914

    
1915
--
1916
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1917
--
1918

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

    
1922
[1] inlining of function calls, which is different from constant folding
1923
[2] _map()''s profiling query
1924
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1925
and map_nulls()''s profiling query
1926
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1927
both take ~920 ms.
1928
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.
1929
';
1930

    
1931

    
1932
--
1933
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1934
--
1935

    
1936
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1937
    LANGUAGE plpgsql STABLE STRICT
1938
    AS $_$
1939
BEGIN
1940
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1941
END;
1942
$_$;
1943

    
1944

    
1945
--
1946
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1947
--
1948

    
1949
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1950
    LANGUAGE sql
1951
    AS $_$
1952
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1953
$$||util.ltrim_nl($2));
1954
-- make sure the created table has the correct estimated row count
1955
SELECT util.analyze_($1);
1956

    
1957
SELECT util.append_comment($1, '
1958
contents generated from:
1959
'||util.ltrim_nl($2)||';
1960
');
1961
$_$;
1962

    
1963

    
1964
--
1965
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1966
--
1967

    
1968
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1969
idempotent
1970
';
1971

    
1972

    
1973
--
1974
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1975
--
1976

    
1977
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1978
    LANGUAGE sql
1979
    AS $_$
1980
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1981
$_$;
1982

    
1983

    
1984
--
1985
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1986
--
1987

    
1988
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1989
idempotent
1990
';
1991

    
1992

    
1993
--
1994
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1995
--
1996

    
1997
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1998
    LANGUAGE sql
1999
    AS $_$
2000
SELECT util.create_if_not_exists($$
2001
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2002
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2003
||quote_literal($2)||$$;
2004
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2005
constant
2006
';
2007
$$)
2008
$_$;
2009

    
2010

    
2011
--
2012
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2013
--
2014

    
2015
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2016
idempotent
2017
';
2018

    
2019

    
2020
--
2021
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2022
--
2023

    
2024
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2025
    LANGUAGE plpgsql STRICT
2026
    AS $_$
2027
DECLARE
2028
    type regtype = util.typeof(expr, col.table_::text::regtype);
2029
    col_name_sql text = quote_ident(col.name);
2030
BEGIN
2031
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2032
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2033
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2034
$$||expr||$$;
2035
$$);
2036
END;
2037
$_$;
2038

    
2039

    
2040
--
2041
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2042
--
2043

    
2044
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2045
idempotent
2046
';
2047

    
2048

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

    
2053
CREATE FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean DEFAULT false, 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
2054
    LANGUAGE sql IMMUTABLE
2055
    AS $_$
2056
SELECT
2057
$$SELECT
2058
$$||$4||$$
2059
FROM $$||$1||$$ left_
2060
$$||util._if($3, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
2061
$$||util._if($3, ''::text,
2062
$$ON $$||$5||$$
2063
$$)||
2064
$$WHERE $$||$6||$$
2065
ORDER BY left_, right_
2066
$$
2067
$_$;
2068

    
2069

    
2070
--
2071
-- Name: FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean, cols text, join_cond text, filter text); Type: COMMENT; Schema: util; Owner: -
2072
--
2073

    
2074
COMMENT ON FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean, cols text, join_cond text, filter text) IS '
2075
single_row: whether the tables consist of a single row, which should be
2076
	displayed side-by-side
2077
';
2078

    
2079

    
2080
--
2081
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2082
--
2083

    
2084
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2085
    LANGUAGE sql
2086
    AS $_$
2087
SELECT util.create_if_not_exists($$
2088
CREATE TABLE $$||$1||$$
2089
(
2090
    LIKE util.map INCLUDING ALL
2091
);
2092

    
2093
CREATE TRIGGER map_filter_insert
2094
  BEFORE INSERT
2095
  ON $$||$1||$$
2096
  FOR EACH ROW
2097
  EXECUTE PROCEDURE util.map_filter_insert();
2098
$$)
2099
$_$;
2100

    
2101

    
2102
--
2103
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2104
--
2105

    
2106
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2107
    LANGUAGE sql IMMUTABLE
2108
    AS $_$
2109
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2110
$_$;
2111

    
2112

    
2113
--
2114
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2115
--
2116

    
2117
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2118
auto-appends util to the search_path to enable use of util operators
2119
';
2120

    
2121

    
2122
--
2123
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2124
--
2125

    
2126
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2127
    LANGUAGE sql IMMUTABLE
2128
    AS $_$
2129
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2130
$_$;
2131

    
2132

    
2133
--
2134
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2135
--
2136

    
2137
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2138
    LANGUAGE sql IMMUTABLE
2139
    AS $_$
2140
/* debug_print_return_value() needed because this function is used with EXECUTE
2141
rather than util.eval() (in order to affect the calling function), so the
2142
search_path would not otherwise be printed */
2143
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2144
||$$ search_path TO $$||$1
2145
$_$;
2146

    
2147

    
2148
--
2149
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2150
--
2151

    
2152
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2153
    LANGUAGE sql
2154
    AS $_$
2155
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2156
$_$;
2157

    
2158

    
2159
--
2160
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2161
--
2162

    
2163
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2164
idempotent
2165
';
2166

    
2167

    
2168
--
2169
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2170
--
2171

    
2172
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2173
    LANGUAGE plpgsql STRICT
2174
    AS $_$
2175
DECLARE
2176
	view_qual_name text = util.qual_name(view_);
2177
BEGIN
2178
	EXECUTE $$
2179
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2180
  RETURNS SETOF $$||view_||$$ AS
2181
$BODY1$
2182
SELECT * FROM $$||view_qual_name||$$
2183
ORDER BY sort_col
2184
LIMIT $1 OFFSET $2
2185
$BODY1$
2186
  LANGUAGE sql STABLE
2187
  COST 100
2188
  ROWS 1000
2189
$$;
2190
	
2191
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2192
END;
2193
$_$;
2194

    
2195

    
2196
--
2197
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2198
--
2199

    
2200
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2201
    LANGUAGE plpgsql STRICT
2202
    AS $_$
2203
DECLARE
2204
	view_qual_name text = util.qual_name(view_);
2205
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2206
BEGIN
2207
	EXECUTE $$
2208
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2209
  RETURNS integer AS
2210
$BODY1$
2211
SELECT $$||quote_ident(row_num_col)||$$
2212
FROM $$||view_qual_name||$$
2213
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2214
LIMIT 1
2215
$BODY1$
2216
  LANGUAGE sql STABLE
2217
  COST 100;
2218
$$;
2219
	
2220
	EXECUTE $$
2221
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2222
  RETURNS SETOF $$||view_||$$ AS
2223
$BODY1$
2224
SELECT * FROM $$||view_qual_name||$$
2225
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2226
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2227
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2228
ORDER BY $$||quote_ident(row_num_col)||$$
2229
$BODY1$
2230
  LANGUAGE sql STABLE
2231
  COST 100
2232
  ROWS 1000
2233
$$;
2234
	
2235
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2236
END;
2237
$_$;
2238

    
2239

    
2240
--
2241
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2242
--
2243

    
2244
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2245
    LANGUAGE plpgsql STRICT
2246
    AS $_$
2247
DECLARE
2248
	view_qual_name text = util.qual_name(view_);
2249
BEGIN
2250
	EXECUTE $$
2251
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2252
  RETURNS SETOF $$||view_||$$
2253
  SET enable_sort TO 'off'
2254
  AS
2255
$BODY1$
2256
SELECT * FROM $$||view_qual_name||$$($2, $3)
2257
$BODY1$
2258
  LANGUAGE sql STABLE
2259
  COST 100
2260
  ROWS 1000
2261
;
2262
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2263
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2264
If you want to run EXPLAIN and get expanded output, use the regular subset
2265
function instead. (When a config param is set on a function, EXPLAIN produces
2266
just a function scan.)
2267
';
2268
$$;
2269
END;
2270
$_$;
2271

    
2272

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

    
2277
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2278
creates subset function which turns off enable_sort
2279
';
2280

    
2281

    
2282
--
2283
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2284
--
2285

    
2286
CREATE FUNCTION name(table_ regclass) RETURNS text
2287
    LANGUAGE sql STABLE
2288
    AS $_$
2289
SELECT relname::text FROM pg_class WHERE oid = $1
2290
$_$;
2291

    
2292

    
2293
--
2294
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2295
--
2296

    
2297
CREATE FUNCTION name(type regtype) RETURNS text
2298
    LANGUAGE sql STABLE
2299
    AS $_$
2300
SELECT typname::text FROM pg_type WHERE oid = $1
2301
$_$;
2302

    
2303

    
2304
--
2305
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2306
--
2307

    
2308
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2309
    LANGUAGE sql IMMUTABLE
2310
    AS $_$
2311
SELECT octet_length($1) >= util.namedatalen() - $2
2312
$_$;
2313

    
2314

    
2315
--
2316
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2317
--
2318

    
2319
CREATE FUNCTION namedatalen() RETURNS integer
2320
    LANGUAGE sql IMMUTABLE
2321
    AS $$
2322
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2323
$$;
2324

    
2325

    
2326
--
2327
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2328
--
2329

    
2330
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2331
    LANGUAGE sql IMMUTABLE
2332
    AS $_$
2333
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2334
$_$;
2335

    
2336

    
2337
--
2338
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2339
--
2340

    
2341
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2342
    LANGUAGE sql IMMUTABLE
2343
    AS $_$
2344
SELECT $1 IS NOT NULL
2345
$_$;
2346

    
2347

    
2348
--
2349
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2350
--
2351

    
2352
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2353
    LANGUAGE sql IMMUTABLE
2354
    AS $_$
2355
SELECT util.hstore($1, NULL) || '*=>*'
2356
$_$;
2357

    
2358

    
2359
--
2360
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2361
--
2362

    
2363
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2364
for use with _map()
2365
';
2366

    
2367

    
2368
--
2369
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2370
--
2371

    
2372
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2373
    LANGUAGE sql IMMUTABLE
2374
    AS $_$
2375
SELECT $2 + COALESCE($1, 0)
2376
$_$;
2377

    
2378

    
2379
--
2380
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2381
--
2382

    
2383
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2384
    LANGUAGE sql
2385
    AS $_$
2386
SELECT util.set_comment($1, concat($2, util.comment($1)))
2387
$_$;
2388

    
2389

    
2390
--
2391
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2392
--
2393

    
2394
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2395
comment: must start and end with a newline
2396
';
2397

    
2398

    
2399
--
2400
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2401
--
2402

    
2403
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2404
    LANGUAGE sql IMMUTABLE
2405
    AS $_$
2406
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2407
$_$;
2408

    
2409

    
2410
--
2411
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2412
--
2413

    
2414
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2415
    LANGUAGE sql STABLE
2416
    SET search_path TO pg_temp
2417
    AS $_$
2418
SELECT $1::text
2419
$_$;
2420

    
2421

    
2422
--
2423
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2424
--
2425

    
2426
CREATE FUNCTION qual_name(type regtype) RETURNS text
2427
    LANGUAGE sql STABLE
2428
    SET search_path TO pg_temp
2429
    AS $_$
2430
SELECT $1::text
2431
$_$;
2432

    
2433

    
2434
--
2435
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2436
--
2437

    
2438
COMMENT ON FUNCTION qual_name(type regtype) IS '
2439
a type''s schema-qualified name
2440
';
2441

    
2442

    
2443
--
2444
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2445
--
2446

    
2447
CREATE FUNCTION qual_name(type unknown) RETURNS text
2448
    LANGUAGE sql STABLE
2449
    AS $_$
2450
SELECT util.qual_name($1::text::regtype)
2451
$_$;
2452

    
2453

    
2454
--
2455
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2456
--
2457

    
2458
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2459
    LANGUAGE sql IMMUTABLE
2460
    AS $_$
2461
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2462
$_$;
2463

    
2464

    
2465
--
2466
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2467
--
2468

    
2469
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2470
    LANGUAGE sql IMMUTABLE
2471
    AS $_$
2472
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2473
$_$;
2474

    
2475

    
2476
--
2477
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2478
--
2479

    
2480
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2481
    LANGUAGE sql IMMUTABLE
2482
    AS $_$
2483
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2484
$_$;
2485

    
2486

    
2487
--
2488
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2489
--
2490

    
2491
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2492
    LANGUAGE sql IMMUTABLE
2493
    AS $_$
2494
SELECT util.raise_notice('ERROR:  '||$1)
2495
$_$;
2496

    
2497

    
2498
--
2499
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2500
--
2501

    
2502
CREATE FUNCTION raise_notice(msg text) RETURNS void
2503
    LANGUAGE plpgsql IMMUTABLE STRICT
2504
    AS $$
2505
BEGIN
2506
	RAISE NOTICE '%', msg;
2507
END;
2508
$$;
2509

    
2510

    
2511
--
2512
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2513
--
2514

    
2515
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2516
    LANGUAGE plpgsql IMMUTABLE STRICT
2517
    AS $$
2518
BEGIN
2519
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2520
END;
2521
$$;
2522

    
2523

    
2524
--
2525
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2526
--
2527

    
2528
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2529
    LANGUAGE sql IMMUTABLE
2530
    AS $_$
2531
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2532
$_$;
2533

    
2534

    
2535
--
2536
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2537
--
2538

    
2539
CREATE FUNCTION regexp_quote(str text) RETURNS text
2540
    LANGUAGE sql IMMUTABLE
2541
    AS $_$
2542
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2543
$_$;
2544

    
2545

    
2546
--
2547
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2548
--
2549

    
2550
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2551
    LANGUAGE sql IMMUTABLE
2552
    AS $_$
2553
SELECT (CASE WHEN right($1, 1) = ')'
2554
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2555
$_$;
2556

    
2557

    
2558
--
2559
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2560
--
2561

    
2562
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2563
    LANGUAGE sql STABLE
2564
    AS $_$
2565
SELECT util.relation_type(util.relation_type_char($1))
2566
$_$;
2567

    
2568

    
2569
--
2570
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2571
--
2572

    
2573
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2574
    LANGUAGE sql IMMUTABLE
2575
    AS $_$
2576
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2577
$_$;
2578

    
2579

    
2580
--
2581
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2582
--
2583

    
2584
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2585
    LANGUAGE sql STABLE
2586
    AS $_$
2587
SELECT relkind FROM pg_class WHERE oid = $1
2588
$_$;
2589

    
2590

    
2591
--
2592
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2593
--
2594

    
2595
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2596
    LANGUAGE sql
2597
    AS $_$
2598
/* can't have in_table/out_table inherit from *each other*, because inheritance
2599
also causes the rows of the parent table to be included in the child table.
2600
instead, they need to inherit from a common, empty table. */
2601
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2602
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2603
SELECT util.inherit($2, $4);
2604
SELECT util.inherit($3, $4);
2605

    
2606
SELECT util.rematerialize_query($1, $$
2607
SELECT * FROM util.diff(
2608
  $$||util.quote_typed($2)||$$
2609
, $$||util.quote_typed($3)||$$
2610
, NULL::$$||$4||$$)
2611
$$);
2612

    
2613
/* the table unfortunately cannot be *materialized* in human-readable form,
2614
because this would create column name collisions between the two sides */
2615
SELECT util.prepend_comment($1, '
2616
to view this table in human-readable form (with each side''s tuple column
2617
expanded to its component fields):
2618
SELECT (left_).*, (right_).* FROM '||$1||';
2619
');
2620
$_$;
2621

    
2622

    
2623
--
2624
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2625
--
2626

    
2627
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2628
type_table (*required*): table to create as the shared base type
2629
';
2630

    
2631

    
2632
--
2633
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2634
--
2635

    
2636
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2637
    LANGUAGE sql
2638
    AS $_$
2639
SELECT util.drop_table($1);
2640
SELECT util.materialize_query($1, $2);
2641
$_$;
2642

    
2643

    
2644
--
2645
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2646
--
2647

    
2648
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2649
idempotent, but repeats action each time
2650
';
2651

    
2652

    
2653
--
2654
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2655
--
2656

    
2657
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2658
    LANGUAGE sql
2659
    AS $_$
2660
SELECT util.drop_table($1);
2661
SELECT util.materialize_view($1, $2);
2662
$_$;
2663

    
2664

    
2665
--
2666
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2667
--
2668

    
2669
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2670
idempotent, but repeats action each time
2671
';
2672

    
2673

    
2674
--
2675
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2676
--
2677

    
2678
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2679
    LANGUAGE sql
2680
    AS $_$
2681
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2682
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2683
FROM util.col_names($1::text::regtype) f (name);
2684
SELECT NULL::void; -- don't fold away functions called in previous query
2685
$_$;
2686

    
2687

    
2688
--
2689
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2690
--
2691

    
2692
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2693
idempotent
2694
';
2695

    
2696

    
2697
--
2698
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2699
--
2700

    
2701
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2702
    LANGUAGE sql
2703
    AS $_$
2704
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2705
included in the debug SQL */
2706
SELECT util.rename_relation(util.qual_name($1), $2)
2707
$_$;
2708

    
2709

    
2710
--
2711
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2712
--
2713

    
2714
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2715
    LANGUAGE sql
2716
    AS $_$
2717
/* 'ALTER TABLE can be used with views too'
2718
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2719
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2720
||quote_ident($2))
2721
$_$;
2722

    
2723

    
2724
--
2725
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2726
--
2727

    
2728
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2729
idempotent
2730
';
2731

    
2732

    
2733
--
2734
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2735
--
2736

    
2737
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2738
    LANGUAGE sql IMMUTABLE
2739
    AS $_$
2740
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2741
$_$;
2742

    
2743

    
2744
--
2745
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2746
--
2747

    
2748
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2749
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 
2750
';
2751

    
2752

    
2753
--
2754
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2755
--
2756

    
2757
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2758
    LANGUAGE sql
2759
    AS $_$
2760
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2761
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2762
SELECT util.set_col_names($1, $2);
2763
$_$;
2764

    
2765

    
2766
--
2767
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2768
--
2769

    
2770
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2771
idempotent.
2772
alters the names table, so it will need to be repopulated after running this function.
2773
';
2774

    
2775

    
2776
--
2777
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2778
--
2779

    
2780
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2781
    LANGUAGE sql
2782
    AS $_$
2783
SELECT util.drop_table($1);
2784
SELECT util.mk_map_table($1);
2785
$_$;
2786

    
2787

    
2788
--
2789
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2790
--
2791

    
2792
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2793
    LANGUAGE sql IMMUTABLE
2794
    AS $_$
2795
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2796
$_$;
2797

    
2798

    
2799
--
2800
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
2801
--
2802

    
2803
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2804
    LANGUAGE sql IMMUTABLE
2805
    AS $_$
2806
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
2807
ELSE util.mk_set_search_path(for_printing := true)||$$;
2808
$$ END)||$1
2809
$_$;
2810

    
2811

    
2812
--
2813
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2814
--
2815

    
2816
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2817
    LANGUAGE plpgsql STRICT
2818
    AS $_$
2819
DECLARE
2820
	result text = NULL;
2821
BEGIN
2822
	BEGIN
2823
		result = util.show_create_view(view_);
2824
		PERFORM util.eval($$DROP VIEW $$||view_);
2825
	EXCEPTION
2826
		WHEN undefined_table THEN NULL;
2827
	END;
2828
	RETURN result;
2829
END;
2830
$_$;
2831

    
2832

    
2833
--
2834
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2835
--
2836

    
2837
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2838
    LANGUAGE sql
2839
    AS $_$
2840
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2841
$_$;
2842

    
2843

    
2844
--
2845
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2846
--
2847

    
2848
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2849
    LANGUAGE sql STABLE
2850
    AS $_$
2851
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2852
$_$;
2853

    
2854

    
2855
--
2856
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2857
--
2858

    
2859
CREATE FUNCTION schema(table_ regclass) RETURNS text
2860
    LANGUAGE sql STABLE
2861
    AS $_$
2862
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2863
$_$;
2864

    
2865

    
2866
--
2867
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2868
--
2869

    
2870
CREATE FUNCTION schema(type regtype) RETURNS text
2871
    LANGUAGE sql STABLE
2872
    AS $_$
2873
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2874
$_$;
2875

    
2876

    
2877
--
2878
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2879
--
2880

    
2881
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2882
    LANGUAGE sql STABLE
2883
    AS $_$
2884
SELECT util.schema(pg_typeof($1))
2885
$_$;
2886

    
2887

    
2888
--
2889
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2890
--
2891

    
2892
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2893
    LANGUAGE sql STABLE
2894
    AS $_$
2895
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2896
$_$;
2897

    
2898

    
2899
--
2900
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2901
--
2902

    
2903
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2904
a schema bundle is a group of schemas with a common prefix
2905
';
2906

    
2907

    
2908
--
2909
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2910
--
2911

    
2912
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2913
    LANGUAGE sql
2914
    AS $_$
2915
SELECT util.schema_rename(old_schema,
2916
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2917
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2918
SELECT NULL::void; -- don't fold away functions called in previous query
2919
$_$;
2920

    
2921

    
2922
--
2923
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2924
--
2925

    
2926
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2927
    LANGUAGE plpgsql
2928
    AS $$
2929
BEGIN
2930
	-- don't schema_bundle_rm() the schema_bundle to keep!
2931
	IF replace = with_ THEN RETURN; END IF;
2932
	
2933
	PERFORM util.schema_bundle_rm(replace);
2934
	PERFORM util.schema_bundle_rename(with_, replace);
2935
END;
2936
$$;
2937

    
2938

    
2939
--
2940
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2941
--
2942

    
2943
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2944
    LANGUAGE sql
2945
    AS $_$
2946
SELECT util.schema_rm(schema)
2947
FROM util.schema_bundle_get_schemas($1) f (schema);
2948
SELECT NULL::void; -- don't fold away functions called in previous query
2949
$_$;
2950

    
2951

    
2952
--
2953
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2954
--
2955

    
2956
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2957
    LANGUAGE sql STABLE
2958
    AS $_$
2959
SELECT quote_ident(util.schema($1))
2960
$_$;
2961

    
2962

    
2963
--
2964
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2965
--
2966

    
2967
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2968
    LANGUAGE sql IMMUTABLE
2969
    AS $_$
2970
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2971
$_$;
2972

    
2973

    
2974
--
2975
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2976
--
2977

    
2978
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2979
    LANGUAGE sql STABLE
2980
    AS $_$
2981
SELECT oid FROM pg_namespace WHERE nspname = $1
2982
$_$;
2983

    
2984

    
2985
--
2986
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
2987
--
2988

    
2989
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
2990
    LANGUAGE sql IMMUTABLE
2991
    AS $_$
2992
SELECT util.schema_regexp(schema_anchor := $1)
2993
$_$;
2994

    
2995

    
2996
--
2997
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
2998
--
2999

    
3000
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3001
    LANGUAGE sql IMMUTABLE
3002
    AS $_$
3003
SELECT util.str_equality_regexp(util.schema($1))
3004
$_$;
3005

    
3006

    
3007
--
3008
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3009
--
3010

    
3011
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3012
    LANGUAGE sql
3013
    AS $_$
3014
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3015
$_$;
3016

    
3017

    
3018
--
3019
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3020
--
3021

    
3022
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3023
    LANGUAGE plpgsql
3024
    AS $$
3025
BEGIN
3026
	-- don't schema_rm() the schema to keep!
3027
	IF replace = with_ THEN RETURN; END IF;
3028
	
3029
	PERFORM util.schema_rm(replace);
3030
	PERFORM util.schema_rename(with_, replace);
3031
END;
3032
$$;
3033

    
3034

    
3035
--
3036
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3037
--
3038

    
3039
CREATE FUNCTION schema_rm(schema text) RETURNS void
3040
    LANGUAGE sql
3041
    AS $_$
3042
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3043
$_$;
3044

    
3045

    
3046
--
3047
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3048
--
3049

    
3050
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3051
    LANGUAGE sql
3052
    AS $_$
3053
SELECT util.eval(
3054
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3055
$_$;
3056

    
3057

    
3058
--
3059
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3060
--
3061

    
3062
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3063
    LANGUAGE plpgsql STRICT
3064
    AS $_$
3065
DECLARE
3066
    old text[] = ARRAY(SELECT util.col_names(table_));
3067
    new text[] = ARRAY(SELECT util.map_values(names));
3068
BEGIN
3069
    old = old[1:array_length(new, 1)]; -- truncate to same length
3070
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3071
||$$ TO $$||quote_ident(value))
3072
    FROM each(hstore(old, new))
3073
    WHERE value != key -- not same name
3074
    ;
3075
END;
3076
$_$;
3077

    
3078

    
3079
--
3080
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3081
--
3082

    
3083
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3084
idempotent
3085
';
3086

    
3087

    
3088
--
3089
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3090
--
3091

    
3092
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3093
    LANGUAGE plpgsql STRICT
3094
    AS $_$
3095
DECLARE
3096
	row_ util.map;
3097
BEGIN
3098
	-- rename any metadata cols rather than re-adding them with new names
3099
	BEGIN
3100
		PERFORM util.set_col_names(table_, names);
3101
	EXCEPTION
3102
		WHEN array_subscript_error THEN -- selective suppress
3103
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3104
				-- metadata cols not yet added
3105
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
3106
			END IF;
3107
	END;
3108
	
3109
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3110
	LOOP
3111
		PERFORM util.mk_const_col((table_, row_."to"),
3112
			substring(row_."from" from 2));
3113
	END LOOP;
3114
	
3115
	PERFORM util.set_col_names(table_, names);
3116
END;
3117
$_$;
3118

    
3119

    
3120
--
3121
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3122
--
3123

    
3124
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3125
idempotent.
3126
the metadata mappings must be *last* in the names table.
3127
';
3128

    
3129

    
3130
--
3131
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3132
--
3133

    
3134
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3135
    LANGUAGE plpgsql STRICT
3136
    AS $_$
3137
DECLARE
3138
    sql text = $$ALTER TABLE $$||table_||$$
3139
$$||NULLIF(array_to_string(ARRAY(
3140
    SELECT
3141
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3142
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3143
    FROM
3144
    (
3145
        SELECT
3146
          quote_ident(col_name) AS col_name_sql
3147
        , util.col_type((table_, col_name)) AS curr_type
3148
        , type AS target_type
3149
        FROM unnest(col_casts)
3150
    ) s
3151
    WHERE curr_type != target_type
3152
), '
3153
, '), '');
3154
BEGIN
3155
    PERFORM util.debug_print_sql(sql);
3156
    EXECUTE COALESCE(sql, '');
3157
END;
3158
$_$;
3159

    
3160

    
3161
--
3162
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3163
--
3164

    
3165
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3166
idempotent
3167
';
3168

    
3169

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

    
3174
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3175
    LANGUAGE sql
3176
    AS $_$
3177
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3178
$_$;
3179

    
3180

    
3181
--
3182
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3183
--
3184

    
3185
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3186
    LANGUAGE sql
3187
    AS $_$
3188
SELECT util.eval(util.mk_set_search_path($1, $2))
3189
$_$;
3190

    
3191

    
3192
--
3193
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3194
--
3195

    
3196
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3197
    LANGUAGE sql STABLE
3198
    AS $_$
3199
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3200
$$||util.show_grants_for($1)
3201
$_$;
3202

    
3203

    
3204
--
3205
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3206
--
3207

    
3208
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3209
    LANGUAGE sql STABLE
3210
    AS $_$
3211
SELECT string_agg(cmd, '')
3212
FROM
3213
(
3214
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3215
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3216
$$ ELSE '' END) AS cmd
3217
	FROM util.grants_users() f (user_)
3218
) s
3219
$_$;
3220

    
3221

    
3222
--
3223
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3224
--
3225

    
3226
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3227
    LANGUAGE sql STABLE
3228
    AS $_$
3229
SELECT oid FROM pg_class
3230
WHERE relkind = ANY($3) AND relname ~ $1
3231
AND util.schema_matches(util.schema(relnamespace), $2)
3232
ORDER BY relname
3233
$_$;
3234

    
3235

    
3236
--
3237
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3238
--
3239

    
3240
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3241
    LANGUAGE sql STABLE
3242
    AS $_$
3243
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3244
$_$;
3245

    
3246

    
3247
--
3248
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3249
--
3250

    
3251
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3252
    LANGUAGE sql IMMUTABLE
3253
    AS $_$
3254
SELECT '^'||util.regexp_quote($1)||'$'
3255
$_$;
3256

    
3257

    
3258
--
3259
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3260
--
3261

    
3262
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3263
    LANGUAGE plpgsql STABLE STRICT
3264
    AS $_$
3265
DECLARE
3266
    hstore hstore;
3267
BEGIN
3268
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3269
        table_||$$))$$ INTO STRICT hstore;
3270
    RETURN hstore;
3271
END;
3272
$_$;
3273

    
3274

    
3275
--
3276
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3277
--
3278

    
3279
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3280
    LANGUAGE sql STABLE
3281
    AS $_$
3282
SELECT COUNT(*) > 0 FROM pg_constraint
3283
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3284
$_$;
3285

    
3286

    
3287
--
3288
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3289
--
3290

    
3291
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3292
gets whether a status flag is set by the presence of a table constraint
3293
';
3294

    
3295

    
3296
--
3297
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3298
--
3299

    
3300
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3301
    LANGUAGE sql
3302
    AS $_$
3303
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3304
||quote_ident($2)||$$ CHECK (true)$$)
3305
$_$;
3306

    
3307

    
3308
--
3309
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3310
--
3311

    
3312
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3313
stores a status flag by the presence of a table constraint.
3314
idempotent.
3315
';
3316

    
3317

    
3318
--
3319
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3320
--
3321

    
3322
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3323
    LANGUAGE sql STABLE
3324
    AS $_$
3325
SELECT util.table_flag__get($1, 'nulls_mapped')
3326
$_$;
3327

    
3328

    
3329
--
3330
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3331
--
3332

    
3333
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3334
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3335
';
3336

    
3337

    
3338
--
3339
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3340
--
3341

    
3342
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3343
    LANGUAGE sql
3344
    AS $_$
3345
SELECT util.table_flag__set($1, 'nulls_mapped')
3346
$_$;
3347

    
3348

    
3349
--
3350
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3351
--
3352

    
3353
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3354
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3355
idempotent.
3356
';
3357

    
3358

    
3359
--
3360
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3361
--
3362

    
3363
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3364
    LANGUAGE plpgsql STRICT
3365
    AS $_$
3366
DECLARE
3367
    row record;
3368
BEGIN
3369
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3370
    LOOP
3371
        IF row.global_name != row.name THEN
3372
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3373
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3374
        END IF;
3375
    END LOOP;
3376
END;
3377
$_$;
3378

    
3379

    
3380
--
3381
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3382
--
3383

    
3384
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3385
idempotent
3386
';
3387

    
3388

    
3389
--
3390
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3391
--
3392

    
3393
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3394
    LANGUAGE sql
3395
    AS $_$
3396
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3397
SELECT NULL::void; -- don't fold away functions called in previous query
3398
$_$;
3399

    
3400

    
3401
--
3402
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3403
--
3404

    
3405
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3406
trims table_ to include only columns in the original data.
3407
idempotent.
3408
';
3409

    
3410

    
3411
--
3412
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3413
--
3414

    
3415
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3416
    LANGUAGE plpgsql STRICT
3417
    AS $_$
3418
BEGIN
3419
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3420
END;
3421
$_$;
3422

    
3423

    
3424
--
3425
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3426
--
3427

    
3428
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3429
idempotent
3430
';
3431

    
3432

    
3433
--
3434
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3435
--
3436

    
3437
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3438
    LANGUAGE sql IMMUTABLE
3439
    AS $_$
3440
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3441
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3442
$_$;
3443

    
3444

    
3445
--
3446
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3447
--
3448

    
3449
CREATE FUNCTION try_create(sql text) RETURNS void
3450
    LANGUAGE plpgsql STRICT
3451
    AS $$
3452
BEGIN
3453
    PERFORM util.eval(sql);
3454
EXCEPTION
3455
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3456
    WHEN undefined_column THEN NULL;
3457
    WHEN duplicate_column THEN NULL;
3458
END;
3459
$$;
3460

    
3461

    
3462
--
3463
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3464
--
3465

    
3466
COMMENT ON FUNCTION try_create(sql text) IS '
3467
idempotent
3468
';
3469

    
3470

    
3471
--
3472
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3473
--
3474

    
3475
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3476
    LANGUAGE sql
3477
    AS $_$
3478
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3479
$_$;
3480

    
3481

    
3482
--
3483
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3484
--
3485

    
3486
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3487
idempotent
3488
';
3489

    
3490

    
3491
--
3492
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3493
--
3494

    
3495
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3496
    LANGUAGE sql IMMUTABLE
3497
    AS $_$
3498
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3499
$_$;
3500

    
3501

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

    
3506
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3507
a type''s NOT NULL qualifier
3508
';
3509

    
3510

    
3511
--
3512
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3513
--
3514

    
3515
CREATE FUNCTION typeof(value anyelement) RETURNS text
3516
    LANGUAGE sql IMMUTABLE
3517
    AS $_$
3518
SELECT util.qual_name(pg_typeof($1))
3519
$_$;
3520

    
3521

    
3522
--
3523
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3524
--
3525

    
3526
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3527
    LANGUAGE plpgsql STABLE
3528
    AS $_$
3529
DECLARE
3530
    type regtype;
3531
BEGIN
3532
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3533
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3534
    RETURN type;
3535
END;
3536
$_$;
3537

    
3538

    
3539
--
3540
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3541
--
3542

    
3543
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3544
    LANGUAGE sql
3545
    AS $_$
3546
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3547
$_$;
3548

    
3549

    
3550
--
3551
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3552
--
3553

    
3554
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3555
auto-appends util to the search_path to enable use of util operators
3556
';
3557

    
3558

    
3559
--
3560
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3561
--
3562

    
3563
CREATE AGGREGATE all_same(anyelement) (
3564
    SFUNC = all_same_transform,
3565
    STYPE = anyarray,
3566
    FINALFUNC = all_same_final
3567
);
3568

    
3569

    
3570
--
3571
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3572
--
3573

    
3574
COMMENT ON AGGREGATE all_same(anyelement) IS '
3575
includes NULLs in comparison
3576
';
3577

    
3578

    
3579
--
3580
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3581
--
3582

    
3583
CREATE AGGREGATE join_strs(text, text) (
3584
    SFUNC = join_strs_transform,
3585
    STYPE = text
3586
);
3587

    
3588

    
3589
--
3590
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3591
--
3592

    
3593
CREATE OPERATOR %== (
3594
    PROCEDURE = "%==",
3595
    LEFTARG = anyelement,
3596
    RIGHTARG = anyelement
3597
);
3598

    
3599

    
3600
--
3601
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3602
--
3603

    
3604
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3605
returns whether the map-keys of the compared values are the same
3606
(mnemonic: % is the Perl symbol for a hash map)
3607

    
3608
should be overridden for types that store both keys and values
3609

    
3610
used in a FULL JOIN to select which columns to join on
3611
';
3612

    
3613

    
3614
--
3615
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3616
--
3617

    
3618
CREATE OPERATOR -> (
3619
    PROCEDURE = map_get,
3620
    LEFTARG = regclass,
3621
    RIGHTARG = text
3622
);
3623

    
3624

    
3625
--
3626
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3627
--
3628

    
3629
CREATE OPERATOR => (
3630
    PROCEDURE = hstore,
3631
    LEFTARG = text[],
3632
    RIGHTARG = text
3633
);
3634

    
3635

    
3636
--
3637
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3638
--
3639

    
3640
COMMENT ON OPERATOR => (text[], text) IS '
3641
usage: array[''key1'', ...]::text[] => ''value''
3642
';
3643

    
3644

    
3645
--
3646
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3647
--
3648

    
3649
CREATE OPERATOR ?*>= (
3650
    PROCEDURE = is_populated_more_often_than,
3651
    LEFTARG = anyelement,
3652
    RIGHTARG = anyelement
3653
);
3654

    
3655

    
3656
--
3657
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3658
--
3659

    
3660
CREATE OPERATOR ?>= (
3661
    PROCEDURE = is_more_complete_than,
3662
    LEFTARG = anyelement,
3663
    RIGHTARG = anyelement
3664
);
3665

    
3666

    
3667
--
3668
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3669
--
3670

    
3671
CREATE OPERATOR ||% (
3672
    PROCEDURE = concat_esc,
3673
    LEFTARG = text,
3674
    RIGHTARG = text
3675
);
3676

    
3677

    
3678
--
3679
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3680
--
3681

    
3682
COMMENT ON OPERATOR ||% (text, text) IS '
3683
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3684
';
3685

    
3686

    
3687
--
3688
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3689
--
3690

    
3691
CREATE TABLE map (
3692
    "from" text NOT NULL,
3693
    "to" text,
3694
    filter text,
3695
    notes text
3696
);
3697

    
3698

    
3699
--
3700
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3701
--
3702

    
3703

    
3704

    
3705
--
3706
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3707
--
3708

    
3709

    
3710

    
3711
--
3712
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3713
--
3714

    
3715
ALTER TABLE ONLY map
3716
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3717

    
3718

    
3719
--
3720
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3721
--
3722

    
3723
ALTER TABLE ONLY map
3724
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3725

    
3726

    
3727
--
3728
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3729
--
3730

    
3731
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3732

    
3733

    
3734
--
3735
-- PostgreSQL database dump complete
3736
--
3737

    
(19-19/29)