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.mk_set_search_path(for_printing := true)||$$;
992
$$||$1||$$
993
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
994
$_$;
995

    
996

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

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

    
1012

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

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

    
1021

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

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

    
1034

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

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

    
1045

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

    
1050
CREATE FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean DEFAULT false, search_path text DEFAULT NULL::text, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1051
    LANGUAGE plpgsql
1052
    SET search_path TO pg_temp
1053
    AS $_$
1054
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1055
changes of search_path (schema elements are bound at inline time rather than
1056
runtime) */
1057
/* function option search_path is needed to limit the effects of
1058
`SET LOCAL search_path` (mk_set_search_path()) to the current function */
1059
BEGIN
1060
	EXECUTE util.mk_set_search_path(concat_ws(', ', search_path, 'util'));
1061
		-- need util.%== as default/fallback
1062
	
1063
	RETURN QUERY
1064
		SELECT * FROM
1065
		util.eval2col_pair($$
1066
SELECT
1067
/* need to explicitly cast each side to the return type because this does not
1068
happen automatically even when an implicit cast is available */
1069
left_::$$||util.typeof($3)||$$, right_::$$||util.typeof($3)||$$
1070
FROM $$||$1||$$ left_
1071
$$||util._if($4, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
1072
$$||util._if($4, ''::text,
1073
$$ON left_ %== right_ -- refer to EXPLAIN output for expansion of %==
1074
$$)||
1075
$$WHERE left_ IS DISTINCT FROM right_
1076
ORDER BY left_, right_
1077
$$, $3)
1078
	;
1079
END;
1080
$_$;
1081

    
1082

    
1083
--
1084
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, search_path text, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1085
--
1086

    
1087
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, search_path text, OUT left_ anyelement, OUT right_ anyelement) IS '
1088
col_type_null (*required*): NULL::col_type
1089
single_row: whether the tables consist of a single row, which should be
1090
	displayed side-by-side
1091

    
1092
to run EXPLAIN on the FULL JOIN query:
1093
# run this function
1094
# look for a NOTICE containing the expanded query that it ran
1095
# run EXPLAIN on this expanded query
1096
';
1097

    
1098

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

    
1103
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1104
    LANGUAGE sql
1105
    AS $_$
1106
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1107
$_$;
1108

    
1109

    
1110
--
1111
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1112
--
1113

    
1114
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1115
idempotent
1116
';
1117

    
1118

    
1119
--
1120
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1121
--
1122

    
1123
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1124
    LANGUAGE sql
1125
    AS $_$
1126
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1127
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1128
$_$;
1129

    
1130

    
1131
--
1132
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1133
--
1134

    
1135
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1136
idempotent
1137
';
1138

    
1139

    
1140
--
1141
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1142
--
1143

    
1144
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1145
    LANGUAGE sql
1146
    AS $_$
1147
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1148
included in the debug SQL */
1149
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1150
$_$;
1151

    
1152

    
1153
--
1154
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1155
--
1156

    
1157
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1158
    LANGUAGE sql
1159
    AS $_$
1160
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1161
||util._if($3, $$ CASCADE$$, ''::text))
1162
$_$;
1163

    
1164

    
1165
--
1166
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1167
--
1168

    
1169
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1170
idempotent
1171
';
1172

    
1173

    
1174
--
1175
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1176
--
1177

    
1178
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1179
    LANGUAGE sql
1180
    AS $_$
1181
SELECT util.drop_relations_like($1, util.str_equality_regexp(util.schema($2)),
1182
$3)
1183
$_$;
1184

    
1185

    
1186
--
1187
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1188
--
1189

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

    
1199

    
1200
--
1201
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1202
--
1203

    
1204
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1205
    LANGUAGE sql
1206
    AS $_$
1207
SELECT util.drop_relation('TABLE', $1, $2)
1208
$_$;
1209

    
1210

    
1211
--
1212
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1213
--
1214

    
1215
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1216
idempotent
1217
';
1218

    
1219

    
1220
--
1221
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1222
--
1223

    
1224
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1225
    LANGUAGE sql
1226
    AS $_$
1227
SELECT util.drop_relation('VIEW', $1, $2)
1228
$_$;
1229

    
1230

    
1231
--
1232
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1233
--
1234

    
1235
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1236
idempotent
1237
';
1238

    
1239

    
1240
--
1241
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1242
--
1243

    
1244
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1245
    LANGUAGE sql IMMUTABLE
1246
    AS $_$
1247
SELECT util.array_fill($1, 0)
1248
$_$;
1249

    
1250

    
1251
--
1252
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1253
--
1254

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

    
1259

    
1260
--
1261
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1262
--
1263

    
1264
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1265
    LANGUAGE sql IMMUTABLE
1266
    AS $_$
1267
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1268
$_$;
1269

    
1270

    
1271
--
1272
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1273
--
1274

    
1275
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1276
    LANGUAGE sql IMMUTABLE
1277
    AS $_$
1278
SELECT regexp_replace($2, '("?)$', $1||'\1')
1279
$_$;
1280

    
1281

    
1282
--
1283
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1284
--
1285

    
1286
CREATE FUNCTION eval(sql text) RETURNS void
1287
    LANGUAGE plpgsql STRICT
1288
    AS $$
1289
BEGIN
1290
	PERFORM util.debug_print_sql(sql);
1291
	EXECUTE sql;
1292
END;
1293
$$;
1294

    
1295

    
1296
--
1297
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1298
--
1299

    
1300
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1301
    LANGUAGE plpgsql
1302
    SET search_path TO pg_temp
1303
    AS $$
1304
/* function option search_path is needed to limit the effects of any
1305
`SET LOCAL search_path` to the current function */
1306
BEGIN
1307
	PERFORM util.debug_print_sql(sql);
1308
	RETURN QUERY EXECUTE sql;
1309
END;
1310
$$;
1311

    
1312

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

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

    
1321

    
1322
--
1323
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1324
--
1325

    
1326
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1327
    LANGUAGE plpgsql
1328
    SET search_path TO pg_temp
1329
    AS $$
1330
/* function option search_path is needed to limit the effects of any
1331
`SET LOCAL search_path` to the current function */
1332
BEGIN
1333
	PERFORM util.debug_print_sql(sql);
1334
	RETURN QUERY EXECUTE sql;
1335
END;
1336
$$;
1337

    
1338

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

    
1343
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1344
    LANGUAGE plpgsql
1345
    SET search_path TO pg_temp
1346
    AS $$
1347
/* function option search_path is needed to limit the effects of any
1348
`SET LOCAL search_path` to the current function */
1349
BEGIN
1350
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1351
	RETURN QUERY EXECUTE sql;
1352
END;
1353
$$;
1354

    
1355

    
1356
--
1357
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1358
--
1359

    
1360
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1361
    LANGUAGE plpgsql
1362
    SET search_path TO pg_temp
1363
    AS $$
1364
/* function option search_path is needed to limit the effects of any
1365
`SET LOCAL search_path` to the current function */
1366
DECLARE
1367
	ret_val ret_type_null%TYPE;
1368
BEGIN
1369
	PERFORM util.debug_print_sql(sql);
1370
	EXECUTE sql INTO STRICT ret_val;
1371
	RETURN ret_val;
1372
END;
1373
$$;
1374

    
1375

    
1376
--
1377
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1378
--
1379

    
1380
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1381
ret_type_null: NULL::ret_type
1382
';
1383

    
1384

    
1385
--
1386
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1387
--
1388

    
1389
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1390
    LANGUAGE sql
1391
    AS $_$
1392
SELECT util.eval2val($$SELECT $$||$1, $2)
1393
$_$;
1394

    
1395

    
1396
--
1397
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1398
--
1399

    
1400
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1401
ret_type_null: NULL::ret_type
1402
';
1403

    
1404

    
1405
--
1406
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1407
--
1408

    
1409
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1410
    LANGUAGE sql
1411
    AS $_$
1412
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1413
$_$;
1414

    
1415

    
1416
--
1417
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1418
--
1419

    
1420
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1421
sql: can be NULL, which will be passed through
1422
ret_type_null: NULL::ret_type
1423
';
1424

    
1425

    
1426
--
1427
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1428
--
1429

    
1430
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1431
    LANGUAGE sql STABLE
1432
    AS $_$
1433
SELECT col_name
1434
FROM unnest($2) s (col_name)
1435
WHERE util.col_exists(($1, col_name))
1436
$_$;
1437

    
1438

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

    
1443
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1444
    LANGUAGE sql
1445
    AS $_$
1446
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1447
$_$;
1448

    
1449

    
1450
--
1451
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1452
--
1453

    
1454
CREATE FUNCTION explain2notice(sql text) RETURNS void
1455
    LANGUAGE sql
1456
    AS $_$
1457
SELECT util.raise_notice(util.explain2notice_msg($1))
1458
$_$;
1459

    
1460

    
1461
--
1462
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1463
--
1464

    
1465
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1466
    LANGUAGE sql
1467
    AS $_$
1468
-- newline before and after to visually separate it from other debug info
1469
SELECT $$
1470
EXPLAIN:
1471
$$||util.explain2str($1)||$$
1472
$$
1473
$_$;
1474

    
1475

    
1476
--
1477
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1478
--
1479

    
1480
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1481
    LANGUAGE sql
1482
    AS $_$
1483
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1484
$_$;
1485

    
1486

    
1487
--
1488
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1489
--
1490

    
1491
CREATE FUNCTION explain2str(sql text) RETURNS text
1492
    LANGUAGE sql
1493
    AS $_$
1494
SELECT util.join_strs(explain, $$
1495
$$) FROM util.explain($1)
1496
$_$;
1497

    
1498

    
1499
SET default_tablespace = '';
1500

    
1501
SET default_with_oids = false;
1502

    
1503
--
1504
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1505
--
1506

    
1507
CREATE TABLE explain (
1508
    line text NOT NULL
1509
);
1510

    
1511

    
1512
--
1513
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1514
--
1515

    
1516
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1517
    LANGUAGE sql
1518
    AS $_$
1519
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1520
$$||quote_nullable($1)||$$
1521
)$$)
1522
$_$;
1523

    
1524

    
1525
--
1526
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1527
--
1528

    
1529
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1530
usage:
1531
PERFORM util.explain2table($$
1532
query
1533
$$);
1534
';
1535

    
1536

    
1537
--
1538
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1539
--
1540

    
1541
CREATE FUNCTION first_word(str text) RETURNS text
1542
    LANGUAGE sql IMMUTABLE
1543
    AS $_$
1544
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1545
$_$;
1546

    
1547

    
1548
--
1549
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1550
--
1551

    
1552
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1553
    LANGUAGE sql IMMUTABLE
1554
    AS $_$
1555
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1556
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1557
) END
1558
$_$;
1559

    
1560

    
1561
--
1562
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1563
--
1564

    
1565
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1566
ensures that an array will always have proper non-NULL dimensions
1567
';
1568

    
1569

    
1570
--
1571
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1572
--
1573

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

    
1594

    
1595
--
1596
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1597
--
1598

    
1599
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1600
idempotent
1601

    
1602
users: not necessary to provide this because it will be autopopulated
1603
';
1604

    
1605

    
1606
--
1607
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1608
--
1609

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

    
1630

    
1631
--
1632
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1633
--
1634

    
1635
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1636
idempotent
1637
';
1638

    
1639

    
1640
--
1641
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1642
--
1643

    
1644
CREATE FUNCTION grants_users() RETURNS SETOF text
1645
    LANGUAGE sql IMMUTABLE
1646
    AS $$
1647
VALUES ('bien_read'), ('public_')
1648
$$;
1649

    
1650

    
1651
--
1652
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1653
--
1654

    
1655
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1656
    LANGUAGE sql IMMUTABLE
1657
    AS $_$
1658
SELECT substring($2 for length($1)) = $1
1659
$_$;
1660

    
1661

    
1662
--
1663
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1664
--
1665

    
1666
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1667
    LANGUAGE sql STABLE
1668
    AS $_$
1669
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1670
$_$;
1671

    
1672

    
1673
--
1674
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1675
--
1676

    
1677
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1678
    LANGUAGE sql IMMUTABLE
1679
    AS $_$
1680
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1681
$_$;
1682

    
1683

    
1684
--
1685
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1686
--
1687

    
1688
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1689
avoids repeating the same value for each key
1690
';
1691

    
1692

    
1693
--
1694
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1695
--
1696

    
1697
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1698
    LANGUAGE sql IMMUTABLE
1699
    AS $_$
1700
SELECT COALESCE($1, $2)
1701
$_$;
1702

    
1703

    
1704
--
1705
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1706
--
1707

    
1708
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1709
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1710
';
1711

    
1712

    
1713
--
1714
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1715
--
1716

    
1717
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1718
    LANGUAGE sql
1719
    AS $_$
1720
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1721
$_$;
1722

    
1723

    
1724
--
1725
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1726
--
1727

    
1728
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1729
    LANGUAGE sql STABLE
1730
    AS $_$
1731
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1732
$_$;
1733

    
1734

    
1735
--
1736
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1737
--
1738

    
1739
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1740
    LANGUAGE sql IMMUTABLE
1741
    AS $_$
1742
SELECT util.array_length($1) = 0
1743
$_$;
1744

    
1745

    
1746
--
1747
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1748
--
1749

    
1750
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1751
    LANGUAGE sql IMMUTABLE
1752
    AS $_$
1753
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1754
$_$;
1755

    
1756

    
1757
--
1758
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1759
--
1760

    
1761
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1762
    LANGUAGE sql IMMUTABLE
1763
    AS $_$
1764
SELECT upper(util.first_word($1)) = ANY(
1765
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1766
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1767
)
1768
$_$;
1769

    
1770

    
1771
--
1772
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1773
--
1774

    
1775
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1776
    LANGUAGE sql IMMUTABLE
1777
    AS $_$
1778
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1779
$_$;
1780

    
1781

    
1782
--
1783
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1784
--
1785

    
1786
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1787
    LANGUAGE sql IMMUTABLE
1788
    AS $_$
1789
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1790
$_$;
1791

    
1792

    
1793
--
1794
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1795
--
1796

    
1797
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1798
    LANGUAGE sql STABLE
1799
    AS $_$
1800
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1801
$_$;
1802

    
1803

    
1804
--
1805
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1806
--
1807

    
1808
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1809
    LANGUAGE sql STABLE
1810
    AS $_$
1811
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1812
$_$;
1813

    
1814

    
1815
--
1816
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1817
--
1818

    
1819
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1820
    LANGUAGE sql IMMUTABLE STRICT
1821
    AS $_$
1822
SELECT $1 || $3 || $2
1823
$_$;
1824

    
1825

    
1826
--
1827
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1828
--
1829

    
1830
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1831
must be declared STRICT to use the special handling of STRICT aggregating functions
1832
';
1833

    
1834

    
1835
--
1836
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1837
--
1838

    
1839
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1840
    LANGUAGE sql IMMUTABLE
1841
    AS $_$
1842
SELECT $1 -- compare on the entire value
1843
$_$;
1844

    
1845

    
1846
--
1847
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1848
--
1849

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

    
1856

    
1857
--
1858
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1859
--
1860

    
1861
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1862
    LANGUAGE sql IMMUTABLE
1863
    AS $_$
1864
SELECT ltrim($1, $$
1865
$$)
1866
$_$;
1867

    
1868

    
1869
--
1870
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1871
--
1872

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

    
1882

    
1883
--
1884
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1885
--
1886

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

    
1899

    
1900
--
1901
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1902
--
1903

    
1904
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1905
    LANGUAGE sql IMMUTABLE
1906
    AS $_$
1907
SELECT util._map(util.nulls_map($1), $2)
1908
$_$;
1909

    
1910

    
1911
--
1912
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1913
--
1914

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

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

    
1927

    
1928
--
1929
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1930
--
1931

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

    
1940

    
1941
--
1942
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1943
--
1944

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

    
1953
SELECT util.append_comment($1, '
1954
contents generated from:
1955
'||util.ltrim_nl($2)||';
1956
');
1957
$_$;
1958

    
1959

    
1960
--
1961
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1962
--
1963

    
1964
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1965
idempotent
1966
';
1967

    
1968

    
1969
--
1970
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1971
--
1972

    
1973
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1974
    LANGUAGE sql
1975
    AS $_$
1976
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1977
$_$;
1978

    
1979

    
1980
--
1981
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1982
--
1983

    
1984
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1985
idempotent
1986
';
1987

    
1988

    
1989
--
1990
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1991
--
1992

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

    
2006

    
2007
--
2008
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2009
--
2010

    
2011
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2012
idempotent
2013
';
2014

    
2015

    
2016
--
2017
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2018
--
2019

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

    
2035

    
2036
--
2037
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2038
--
2039

    
2040
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2041
idempotent
2042
';
2043

    
2044

    
2045
--
2046
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2047
--
2048

    
2049
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2050
    LANGUAGE sql
2051
    AS $_$
2052
SELECT util.create_if_not_exists($$
2053
CREATE TABLE $$||$1||$$
2054
(
2055
    LIKE util.map INCLUDING ALL
2056
);
2057

    
2058
CREATE TRIGGER map_filter_insert
2059
  BEFORE INSERT
2060
  ON $$||$1||$$
2061
  FOR EACH ROW
2062
  EXECUTE PROCEDURE util.map_filter_insert();
2063
$$)
2064
$_$;
2065

    
2066

    
2067
--
2068
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2069
--
2070

    
2071
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2072
    LANGUAGE sql IMMUTABLE
2073
    AS $_$
2074
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
2075
$_$;
2076

    
2077

    
2078
--
2079
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2080
--
2081

    
2082
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
2083
    LANGUAGE sql IMMUTABLE
2084
    AS $_$
2085
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
2086
$_$;
2087

    
2088

    
2089
--
2090
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2091
--
2092

    
2093
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
2094
usage:
2095
for *1* schema arg:
2096
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
2097
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2098
';
2099

    
2100

    
2101
--
2102
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2103
--
2104

    
2105
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2106
    LANGUAGE sql IMMUTABLE
2107
    AS $_$
2108
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2109
$_$;
2110

    
2111

    
2112
--
2113
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2114
--
2115

    
2116
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2117
    LANGUAGE sql IMMUTABLE
2118
    AS $_$
2119
/* debug_print_return_value() needed because this function is used with EXECUTE
2120
rather than util.eval() (in order to affect the calling function), so the
2121
search_path would not otherwise be printed */
2122
SELECT util.debug_print_return_value($$SET$$
2123
||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$) ||$$ search_path TO $$||$1)
2124
$_$;
2125

    
2126

    
2127
--
2128
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2129
--
2130

    
2131
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2132
    LANGUAGE sql
2133
    AS $_$
2134
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2135
$_$;
2136

    
2137

    
2138
--
2139
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2140
--
2141

    
2142
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2143
idempotent
2144
';
2145

    
2146

    
2147
--
2148
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2149
--
2150

    
2151
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2152
    LANGUAGE plpgsql STRICT
2153
    AS $_$
2154
DECLARE
2155
	view_qual_name text = util.qual_name(view_);
2156
BEGIN
2157
	EXECUTE $$
2158
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2159
  RETURNS SETOF $$||view_||$$ AS
2160
$BODY1$
2161
SELECT * FROM $$||view_qual_name||$$
2162
ORDER BY sort_col
2163
LIMIT $1 OFFSET $2
2164
$BODY1$
2165
  LANGUAGE sql STABLE
2166
  COST 100
2167
  ROWS 1000
2168
$$;
2169
	
2170
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2171
END;
2172
$_$;
2173

    
2174

    
2175
--
2176
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2177
--
2178

    
2179
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2180
    LANGUAGE plpgsql STRICT
2181
    AS $_$
2182
DECLARE
2183
	view_qual_name text = util.qual_name(view_);
2184
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2185
BEGIN
2186
	EXECUTE $$
2187
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2188
  RETURNS integer AS
2189
$BODY1$
2190
SELECT $$||quote_ident(row_num_col)||$$
2191
FROM $$||view_qual_name||$$
2192
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2193
LIMIT 1
2194
$BODY1$
2195
  LANGUAGE sql STABLE
2196
  COST 100;
2197
$$;
2198
	
2199
	EXECUTE $$
2200
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2201
  RETURNS SETOF $$||view_||$$ AS
2202
$BODY1$
2203
SELECT * FROM $$||view_qual_name||$$
2204
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2205
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2206
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2207
ORDER BY $$||quote_ident(row_num_col)||$$
2208
$BODY1$
2209
  LANGUAGE sql STABLE
2210
  COST 100
2211
  ROWS 1000
2212
$$;
2213
	
2214
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2215
END;
2216
$_$;
2217

    
2218

    
2219
--
2220
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2221
--
2222

    
2223
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2224
    LANGUAGE plpgsql STRICT
2225
    AS $_$
2226
DECLARE
2227
	view_qual_name text = util.qual_name(view_);
2228
BEGIN
2229
	EXECUTE $$
2230
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2231
  RETURNS SETOF $$||view_||$$
2232
  SET enable_sort TO 'off'
2233
  AS
2234
$BODY1$
2235
SELECT * FROM $$||view_qual_name||$$($2, $3)
2236
$BODY1$
2237
  LANGUAGE sql STABLE
2238
  COST 100
2239
  ROWS 1000
2240
;
2241
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2242
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2243
If you want to run EXPLAIN and get expanded output, use the regular subset
2244
function instead. (When a config param is set on a function, EXPLAIN produces
2245
just a function scan.)
2246
';
2247
$$;
2248
END;
2249
$_$;
2250

    
2251

    
2252
--
2253
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2254
--
2255

    
2256
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2257
creates subset function which turns off enable_sort
2258
';
2259

    
2260

    
2261
--
2262
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2263
--
2264

    
2265
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2266
    LANGUAGE sql IMMUTABLE
2267
    AS $_$
2268
SELECT util.mk_set_search_path(util.schema_esc($1))
2269
$_$;
2270

    
2271

    
2272
--
2273
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2274
--
2275

    
2276
CREATE FUNCTION name(table_ regclass) RETURNS text
2277
    LANGUAGE sql STABLE
2278
    AS $_$
2279
SELECT relname::text FROM pg_class WHERE oid = $1
2280
$_$;
2281

    
2282

    
2283
--
2284
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2285
--
2286

    
2287
CREATE FUNCTION name(type regtype) RETURNS text
2288
    LANGUAGE sql STABLE
2289
    AS $_$
2290
SELECT typname::text FROM pg_type WHERE oid = $1
2291
$_$;
2292

    
2293

    
2294
--
2295
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2296
--
2297

    
2298
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2299
    LANGUAGE sql IMMUTABLE
2300
    AS $_$
2301
SELECT octet_length($1) >= util.namedatalen() - $2
2302
$_$;
2303

    
2304

    
2305
--
2306
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2307
--
2308

    
2309
CREATE FUNCTION namedatalen() RETURNS integer
2310
    LANGUAGE sql IMMUTABLE
2311
    AS $$
2312
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2313
$$;
2314

    
2315

    
2316
--
2317
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2318
--
2319

    
2320
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2321
    LANGUAGE sql IMMUTABLE
2322
    AS $_$
2323
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2324
$_$;
2325

    
2326

    
2327
--
2328
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2329
--
2330

    
2331
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2332
    LANGUAGE sql IMMUTABLE
2333
    AS $_$
2334
SELECT $1 IS NOT NULL
2335
$_$;
2336

    
2337

    
2338
--
2339
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2340
--
2341

    
2342
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2343
    LANGUAGE sql IMMUTABLE
2344
    AS $_$
2345
SELECT util.hstore($1, NULL) || '*=>*'
2346
$_$;
2347

    
2348

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

    
2353
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2354
for use with _map()
2355
';
2356

    
2357

    
2358
--
2359
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2360
--
2361

    
2362
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2363
    LANGUAGE sql IMMUTABLE
2364
    AS $_$
2365
SELECT $2 + COALESCE($1, 0)
2366
$_$;
2367

    
2368

    
2369
--
2370
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2371
--
2372

    
2373
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2374
    LANGUAGE sql IMMUTABLE
2375
    AS $_$
2376
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2377
$_$;
2378

    
2379

    
2380
--
2381
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2382
--
2383

    
2384
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2385
    LANGUAGE sql STABLE
2386
    SET search_path TO pg_temp
2387
    AS $_$
2388
SELECT $1::text
2389
$_$;
2390

    
2391

    
2392
--
2393
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2394
--
2395

    
2396
CREATE FUNCTION qual_name(type regtype) RETURNS text
2397
    LANGUAGE sql STABLE
2398
    SET search_path TO pg_temp
2399
    AS $_$
2400
SELECT $1::text
2401
$_$;
2402

    
2403

    
2404
--
2405
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2406
--
2407

    
2408
COMMENT ON FUNCTION qual_name(type regtype) IS '
2409
a type''s schema-qualified name
2410
';
2411

    
2412

    
2413
--
2414
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2415
--
2416

    
2417
CREATE FUNCTION qual_name(type unknown) RETURNS text
2418
    LANGUAGE sql STABLE
2419
    AS $_$
2420
SELECT util.qual_name($1::text::regtype)
2421
$_$;
2422

    
2423

    
2424
--
2425
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2426
--
2427

    
2428
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2429
    LANGUAGE sql IMMUTABLE
2430
    AS $_$
2431
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2432
$_$;
2433

    
2434

    
2435
--
2436
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2437
--
2438

    
2439
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2440
    LANGUAGE sql IMMUTABLE
2441
    AS $_$
2442
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2443
$_$;
2444

    
2445

    
2446
--
2447
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2448
--
2449

    
2450
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2451
    LANGUAGE sql IMMUTABLE
2452
    AS $_$
2453
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2454
$_$;
2455

    
2456

    
2457
--
2458
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2459
--
2460

    
2461
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2462
    LANGUAGE sql IMMUTABLE
2463
    AS $_$
2464
SELECT util.raise_notice('ERROR:  '||$1)
2465
$_$;
2466

    
2467

    
2468
--
2469
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2470
--
2471

    
2472
CREATE FUNCTION raise_notice(msg text) RETURNS void
2473
    LANGUAGE plpgsql IMMUTABLE STRICT
2474
    AS $$
2475
BEGIN
2476
	RAISE NOTICE '%', msg;
2477
END;
2478
$$;
2479

    
2480

    
2481
--
2482
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2483
--
2484

    
2485
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2486
    LANGUAGE plpgsql IMMUTABLE STRICT
2487
    AS $$
2488
BEGIN
2489
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2490
END;
2491
$$;
2492

    
2493

    
2494
--
2495
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2496
--
2497

    
2498
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2499
    LANGUAGE sql IMMUTABLE
2500
    AS $_$
2501
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2502
$_$;
2503

    
2504

    
2505
--
2506
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2507
--
2508

    
2509
CREATE FUNCTION regexp_quote(str text) RETURNS text
2510
    LANGUAGE sql IMMUTABLE
2511
    AS $_$
2512
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2513
$_$;
2514

    
2515

    
2516
--
2517
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2518
--
2519

    
2520
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2521
    LANGUAGE sql IMMUTABLE
2522
    AS $_$
2523
SELECT (CASE WHEN right($1, 1) = ')'
2524
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2525
$_$;
2526

    
2527

    
2528
--
2529
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2530
--
2531

    
2532
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2533
    LANGUAGE sql STABLE
2534
    AS $_$
2535
SELECT util.relation_type(util.relation_type_char($1))
2536
$_$;
2537

    
2538

    
2539
--
2540
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2541
--
2542

    
2543
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2544
    LANGUAGE sql IMMUTABLE
2545
    AS $_$
2546
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2547
$_$;
2548

    
2549

    
2550
--
2551
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2552
--
2553

    
2554
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2555
    LANGUAGE sql STABLE
2556
    AS $_$
2557
SELECT relkind FROM pg_class WHERE oid = $1
2558
$_$;
2559

    
2560

    
2561
--
2562
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2563
--
2564

    
2565
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2566
    LANGUAGE sql
2567
    AS $_$
2568
/* can't have in_table/out_table inherit from *each other*, because inheritance
2569
also causes the rows of the parent table to be included in the child table.
2570
instead, they need to inherit from a common, empty table. */
2571
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2572
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2573
SELECT util.inherit($2, $4);
2574
SELECT util.inherit($3, $4);
2575

    
2576
SELECT util.rematerialize_query($1, $$
2577
SELECT * FROM util.diff(
2578
  $$||util.quote_typed($2)||$$
2579
, $$||util.quote_typed($3)||$$
2580
, NULL::$$||$4||$$)
2581
$$);
2582

    
2583
/* the table unfortunately cannot be *materialized* in human-readable form,
2584
because this would create column name collisions between the two sides */
2585
SELECT util.append_comment($1, '
2586
to view this table in human-readable form (with each side''s tuple column
2587
expanded to its component fields):
2588
SELECT (left_).*, (right_).* FROM '||$1||';
2589
');
2590
$_$;
2591

    
2592

    
2593
--
2594
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2595
--
2596

    
2597
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2598
type_table (*required*): table to create as the shared base type
2599
';
2600

    
2601

    
2602
--
2603
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2604
--
2605

    
2606
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2607
    LANGUAGE sql
2608
    AS $_$
2609
SELECT util.drop_table($1);
2610
SELECT util.materialize_query($1, $2);
2611
$_$;
2612

    
2613

    
2614
--
2615
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2616
--
2617

    
2618
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2619
idempotent, but repeats action each time
2620
';
2621

    
2622

    
2623
--
2624
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2625
--
2626

    
2627
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2628
    LANGUAGE sql
2629
    AS $_$
2630
SELECT util.drop_table($1);
2631
SELECT util.materialize_view($1, $2);
2632
$_$;
2633

    
2634

    
2635
--
2636
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2637
--
2638

    
2639
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2640
idempotent, but repeats action each time
2641
';
2642

    
2643

    
2644
--
2645
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2646
--
2647

    
2648
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2649
    LANGUAGE sql
2650
    AS $_$
2651
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2652
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2653
FROM util.col_names($1::text::regtype) f (name);
2654
SELECT NULL::void; -- don't fold away functions called in previous query
2655
$_$;
2656

    
2657

    
2658
--
2659
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2660
--
2661

    
2662
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2663
idempotent
2664
';
2665

    
2666

    
2667
--
2668
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2669
--
2670

    
2671
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2672
    LANGUAGE sql
2673
    AS $_$
2674
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2675
included in the debug SQL */
2676
SELECT util.rename_relation(util.qual_name($1), $2)
2677
$_$;
2678

    
2679

    
2680
--
2681
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2682
--
2683

    
2684
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2685
    LANGUAGE sql
2686
    AS $_$
2687
/* 'ALTER TABLE can be used with views too'
2688
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2689
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2690
||quote_ident($2))
2691
$_$;
2692

    
2693

    
2694
--
2695
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2696
--
2697

    
2698
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2699
idempotent
2700
';
2701

    
2702

    
2703
--
2704
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2705
--
2706

    
2707
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2708
    LANGUAGE sql IMMUTABLE
2709
    AS $_$
2710
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2711
$_$;
2712

    
2713

    
2714
--
2715
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2716
--
2717

    
2718
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2719
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 
2720
';
2721

    
2722

    
2723
--
2724
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2725
--
2726

    
2727
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2728
    LANGUAGE sql
2729
    AS $_$
2730
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2731
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2732
SELECT util.set_col_names($1, $2);
2733
$_$;
2734

    
2735

    
2736
--
2737
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2738
--
2739

    
2740
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2741
idempotent.
2742
alters the names table, so it will need to be repopulated after running this function.
2743
';
2744

    
2745

    
2746
--
2747
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2748
--
2749

    
2750
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2751
    LANGUAGE sql
2752
    AS $_$
2753
SELECT util.drop_table($1);
2754
SELECT util.mk_map_table($1);
2755
$_$;
2756

    
2757

    
2758
--
2759
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2760
--
2761

    
2762
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2763
    LANGUAGE sql IMMUTABLE
2764
    AS $_$
2765
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2766
$_$;
2767

    
2768

    
2769
--
2770
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772

    
2773
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2774
    LANGUAGE sql IMMUTABLE
2775
    AS $_$
2776
SELECT util.mk_set_search_path(for_printing := true)||$$;
2777
$$||$1
2778
$_$;
2779

    
2780

    
2781
--
2782
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2783
--
2784

    
2785
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2786
    LANGUAGE plpgsql STRICT
2787
    AS $_$
2788
DECLARE
2789
	result text = NULL;
2790
BEGIN
2791
	BEGIN
2792
		result = util.show_create_view(view_);
2793
		PERFORM util.eval($$DROP VIEW $$||view_);
2794
	EXCEPTION
2795
		WHEN undefined_table THEN NULL;
2796
	END;
2797
	RETURN result;
2798
END;
2799
$_$;
2800

    
2801

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

    
2806
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2807
    LANGUAGE sql
2808
    AS $_$
2809
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2810
$_$;
2811

    
2812

    
2813
--
2814
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2815
--
2816

    
2817
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2818
    LANGUAGE sql STABLE
2819
    AS $_$
2820
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2821
$_$;
2822

    
2823

    
2824
--
2825
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2826
--
2827

    
2828
CREATE FUNCTION schema(table_ regclass) RETURNS text
2829
    LANGUAGE sql STABLE
2830
    AS $_$
2831
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2832
$_$;
2833

    
2834

    
2835
--
2836
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2837
--
2838

    
2839
CREATE FUNCTION schema(type regtype) RETURNS text
2840
    LANGUAGE sql STABLE
2841
    AS $_$
2842
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2843
$_$;
2844

    
2845

    
2846
--
2847
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2848
--
2849

    
2850
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2851
    LANGUAGE sql STABLE
2852
    AS $_$
2853
SELECT util.schema(pg_typeof($1))
2854
$_$;
2855

    
2856

    
2857
--
2858
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2859
--
2860

    
2861
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2862
    LANGUAGE sql STABLE
2863
    AS $_$
2864
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2865
$_$;
2866

    
2867

    
2868
--
2869
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2870
--
2871

    
2872
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2873
a schema bundle is a group of schemas with a common prefix
2874
';
2875

    
2876

    
2877
--
2878
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2879
--
2880

    
2881
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2882
    LANGUAGE sql
2883
    AS $_$
2884
SELECT util.schema_rename(old_schema,
2885
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2886
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2887
SELECT NULL::void; -- don't fold away functions called in previous query
2888
$_$;
2889

    
2890

    
2891
--
2892
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2893
--
2894

    
2895
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2896
    LANGUAGE plpgsql
2897
    AS $$
2898
BEGIN
2899
	-- don't schema_bundle_rm() the schema_bundle to keep!
2900
	IF replace = with_ THEN RETURN; END IF;
2901
	
2902
	PERFORM util.schema_bundle_rm(replace);
2903
	PERFORM util.schema_bundle_rename(with_, replace);
2904
END;
2905
$$;
2906

    
2907

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

    
2912
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2913
    LANGUAGE sql
2914
    AS $_$
2915
SELECT util.schema_rm(schema)
2916
FROM util.schema_bundle_get_schemas($1) f (schema);
2917
SELECT NULL::void; -- don't fold away functions called in previous query
2918
$_$;
2919

    
2920

    
2921
--
2922
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2923
--
2924

    
2925
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2926
    LANGUAGE sql STABLE
2927
    AS $_$
2928
SELECT quote_ident(util.schema($1))
2929
$_$;
2930

    
2931

    
2932
--
2933
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2934
--
2935

    
2936
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2937
    LANGUAGE sql IMMUTABLE
2938
    AS $_$
2939
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2940
$_$;
2941

    
2942

    
2943
--
2944
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2945
--
2946

    
2947
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2948
    LANGUAGE sql STABLE
2949
    AS $_$
2950
SELECT oid FROM pg_namespace WHERE nspname = $1
2951
$_$;
2952

    
2953

    
2954
--
2955
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2956
--
2957

    
2958
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2959
    LANGUAGE sql
2960
    AS $_$
2961
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2962
$_$;
2963

    
2964

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

    
2969
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2970
    LANGUAGE plpgsql
2971
    AS $$
2972
BEGIN
2973
	-- don't schema_rm() the schema to keep!
2974
	IF replace = with_ THEN RETURN; END IF;
2975
	
2976
	PERFORM util.schema_rm(replace);
2977
	PERFORM util.schema_rename(with_, replace);
2978
END;
2979
$$;
2980

    
2981

    
2982
--
2983
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2984
--
2985

    
2986
CREATE FUNCTION schema_rm(schema text) RETURNS void
2987
    LANGUAGE sql
2988
    AS $_$
2989
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2990
$_$;
2991

    
2992

    
2993
--
2994
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2995
--
2996

    
2997
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2998
    LANGUAGE sql
2999
    AS $_$
3000
SELECT util.eval(
3001
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3002
$_$;
3003

    
3004

    
3005
--
3006
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3007
--
3008

    
3009
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3010
    LANGUAGE plpgsql STRICT
3011
    AS $_$
3012
DECLARE
3013
    old text[] = ARRAY(SELECT util.col_names(table_));
3014
    new text[] = ARRAY(SELECT util.map_values(names));
3015
BEGIN
3016
    old = old[1:array_length(new, 1)]; -- truncate to same length
3017
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3018
||$$ TO $$||quote_ident(value))
3019
    FROM each(hstore(old, new))
3020
    WHERE value != key -- not same name
3021
    ;
3022
END;
3023
$_$;
3024

    
3025

    
3026
--
3027
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3028
--
3029

    
3030
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3031
idempotent
3032
';
3033

    
3034

    
3035
--
3036
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3037
--
3038

    
3039
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3040
    LANGUAGE plpgsql STRICT
3041
    AS $_$
3042
DECLARE
3043
	row_ util.map;
3044
BEGIN
3045
	-- rename any metadata cols rather than re-adding them with new names
3046
	BEGIN
3047
		PERFORM util.set_col_names(table_, names);
3048
	EXCEPTION
3049
		WHEN array_subscript_error THEN -- selective suppress
3050
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3051
				-- metadata cols not yet added
3052
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
3053
			END IF;
3054
	END;
3055
	
3056
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3057
	LOOP
3058
		PERFORM util.mk_const_col((table_, row_."to"),
3059
			substring(row_."from" from 2));
3060
	END LOOP;
3061
	
3062
	PERFORM util.set_col_names(table_, names);
3063
END;
3064
$_$;
3065

    
3066

    
3067
--
3068
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3069
--
3070

    
3071
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3072
idempotent.
3073
the metadata mappings must be *last* in the names table.
3074
';
3075

    
3076

    
3077
--
3078
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3079
--
3080

    
3081
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3082
    LANGUAGE plpgsql STRICT
3083
    AS $_$
3084
DECLARE
3085
    sql text = $$ALTER TABLE $$||table_||$$
3086
$$||NULLIF(array_to_string(ARRAY(
3087
    SELECT
3088
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3089
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3090
    FROM
3091
    (
3092
        SELECT
3093
          quote_ident(col_name) AS col_name_sql
3094
        , util.col_type((table_, col_name)) AS curr_type
3095
        , type AS target_type
3096
        FROM unnest(col_casts)
3097
    ) s
3098
    WHERE curr_type != target_type
3099
), '
3100
, '), '');
3101
BEGIN
3102
    PERFORM util.debug_print_sql(sql);
3103
    EXECUTE COALESCE(sql, '');
3104
END;
3105
$_$;
3106

    
3107

    
3108
--
3109
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3110
--
3111

    
3112
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3113
idempotent
3114
';
3115

    
3116

    
3117
--
3118
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3119
--
3120

    
3121
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3122
    LANGUAGE sql
3123
    AS $_$
3124
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3125
$_$;
3126

    
3127

    
3128
--
3129
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3130
--
3131

    
3132
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3133
    LANGUAGE sql STABLE
3134
    AS $_$
3135
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3136
$$||util.show_grants_for($1)
3137
$_$;
3138

    
3139

    
3140
--
3141
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3142
--
3143

    
3144
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3145
    LANGUAGE sql STABLE
3146
    AS $_$
3147
SELECT string_agg(cmd, '')
3148
FROM
3149
(
3150
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3151
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3152
$$ ELSE '' END) AS cmd
3153
	FROM util.grants_users() f (user_)
3154
) s
3155
$_$;
3156

    
3157

    
3158
--
3159
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3160
--
3161

    
3162
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3163
    LANGUAGE sql STABLE
3164
    AS $_$
3165
SELECT oid FROM pg_class
3166
WHERE relkind = ANY($3) AND relname ~ $1
3167
AND util.schema_matches(util.schema(relnamespace), $2)
3168
ORDER BY relname
3169
$_$;
3170

    
3171

    
3172
--
3173
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3174
--
3175

    
3176
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3177
    LANGUAGE sql STABLE
3178
    AS $_$
3179
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3180
$_$;
3181

    
3182

    
3183
--
3184
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3185
--
3186

    
3187
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3188
    LANGUAGE sql IMMUTABLE
3189
    AS $_$
3190
SELECT '^'||util.regexp_quote($1)||'$'
3191
$_$;
3192

    
3193

    
3194
--
3195
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3196
--
3197

    
3198
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3199
    LANGUAGE plpgsql STABLE STRICT
3200
    AS $_$
3201
DECLARE
3202
    hstore hstore;
3203
BEGIN
3204
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3205
        table_||$$))$$ INTO STRICT hstore;
3206
    RETURN hstore;
3207
END;
3208
$_$;
3209

    
3210

    
3211
--
3212
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3213
--
3214

    
3215
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3216
    LANGUAGE sql STABLE
3217
    AS $_$
3218
SELECT COUNT(*) > 0 FROM pg_constraint
3219
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3220
$_$;
3221

    
3222

    
3223
--
3224
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3225
--
3226

    
3227
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3228
gets whether a status flag is set by the presence of a table constraint
3229
';
3230

    
3231

    
3232
--
3233
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3234
--
3235

    
3236
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3237
    LANGUAGE sql
3238
    AS $_$
3239
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3240
||quote_ident($2)||$$ CHECK (true)$$)
3241
$_$;
3242

    
3243

    
3244
--
3245
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3246
--
3247

    
3248
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3249
stores a status flag by the presence of a table constraint.
3250
idempotent.
3251
';
3252

    
3253

    
3254
--
3255
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3256
--
3257

    
3258
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3259
    LANGUAGE sql STABLE
3260
    AS $_$
3261
SELECT util.table_flag__get($1, 'nulls_mapped')
3262
$_$;
3263

    
3264

    
3265
--
3266
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3267
--
3268

    
3269
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3270
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3271
';
3272

    
3273

    
3274
--
3275
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3276
--
3277

    
3278
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3279
    LANGUAGE sql
3280
    AS $_$
3281
SELECT util.table_flag__set($1, 'nulls_mapped')
3282
$_$;
3283

    
3284

    
3285
--
3286
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3287
--
3288

    
3289
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3290
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3291
idempotent.
3292
';
3293

    
3294

    
3295
--
3296
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3297
--
3298

    
3299
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3300
    LANGUAGE plpgsql STRICT
3301
    AS $_$
3302
DECLARE
3303
    row record;
3304
BEGIN
3305
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3306
    LOOP
3307
        IF row.global_name != row.name THEN
3308
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3309
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3310
        END IF;
3311
    END LOOP;
3312
END;
3313
$_$;
3314

    
3315

    
3316
--
3317
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3318
--
3319

    
3320
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3321
idempotent
3322
';
3323

    
3324

    
3325
--
3326
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3327
--
3328

    
3329
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3330
    LANGUAGE sql
3331
    AS $_$
3332
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3333
SELECT NULL::void; -- don't fold away functions called in previous query
3334
$_$;
3335

    
3336

    
3337
--
3338
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3339
--
3340

    
3341
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3342
trims table_ to include only columns in the original data.
3343
idempotent.
3344
';
3345

    
3346

    
3347
--
3348
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3349
--
3350

    
3351
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3352
    LANGUAGE plpgsql STRICT
3353
    AS $_$
3354
BEGIN
3355
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3356
END;
3357
$_$;
3358

    
3359

    
3360
--
3361
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3362
--
3363

    
3364
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3365
idempotent
3366
';
3367

    
3368

    
3369
--
3370
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3371
--
3372

    
3373
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3374
    LANGUAGE sql IMMUTABLE
3375
    AS $_$
3376
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3377
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3378
$_$;
3379

    
3380

    
3381
--
3382
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3383
--
3384

    
3385
CREATE FUNCTION try_create(sql text) RETURNS void
3386
    LANGUAGE plpgsql STRICT
3387
    AS $$
3388
BEGIN
3389
    PERFORM util.eval(sql);
3390
EXCEPTION
3391
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3392
    WHEN undefined_column THEN NULL;
3393
    WHEN duplicate_column THEN NULL;
3394
END;
3395
$$;
3396

    
3397

    
3398
--
3399
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3400
--
3401

    
3402
COMMENT ON FUNCTION try_create(sql text) IS '
3403
idempotent
3404
';
3405

    
3406

    
3407
--
3408
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3409
--
3410

    
3411
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3412
    LANGUAGE sql
3413
    AS $_$
3414
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3415
$_$;
3416

    
3417

    
3418
--
3419
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3420
--
3421

    
3422
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3423
idempotent
3424
';
3425

    
3426

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

    
3431
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3432
    LANGUAGE sql IMMUTABLE
3433
    AS $_$
3434
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3435
$_$;
3436

    
3437

    
3438
--
3439
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3440
--
3441

    
3442
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3443
a type''s NOT NULL qualifier
3444
';
3445

    
3446

    
3447
--
3448
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3449
--
3450

    
3451
CREATE FUNCTION typeof(value anyelement) RETURNS text
3452
    LANGUAGE sql IMMUTABLE
3453
    AS $_$
3454
SELECT util.qual_name(pg_typeof($1))
3455
$_$;
3456

    
3457

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

    
3462
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3463
    LANGUAGE plpgsql STABLE
3464
    AS $_$
3465
DECLARE
3466
    type regtype;
3467
BEGIN
3468
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3469
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3470
    RETURN type;
3471
END;
3472
$_$;
3473

    
3474

    
3475
--
3476
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3477
--
3478

    
3479
CREATE AGGREGATE all_same(anyelement) (
3480
    SFUNC = all_same_transform,
3481
    STYPE = anyarray,
3482
    FINALFUNC = all_same_final
3483
);
3484

    
3485

    
3486
--
3487
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3488
--
3489

    
3490
COMMENT ON AGGREGATE all_same(anyelement) IS '
3491
includes NULLs in comparison
3492
';
3493

    
3494

    
3495
--
3496
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3497
--
3498

    
3499
CREATE AGGREGATE join_strs(text, text) (
3500
    SFUNC = join_strs_transform,
3501
    STYPE = text
3502
);
3503

    
3504

    
3505
--
3506
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3507
--
3508

    
3509
CREATE OPERATOR %== (
3510
    PROCEDURE = "%==",
3511
    LEFTARG = anyelement,
3512
    RIGHTARG = anyelement
3513
);
3514

    
3515

    
3516
--
3517
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3518
--
3519

    
3520
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3521
returns whether the map-keys of the compared values are the same
3522
(mnemonic: % is the Perl symbol for a hash map)
3523

    
3524
should be overridden for types that store both keys and values
3525

    
3526
used in a FULL JOIN to select which columns to join on
3527
';
3528

    
3529

    
3530
--
3531
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3532
--
3533

    
3534
CREATE OPERATOR -> (
3535
    PROCEDURE = map_get,
3536
    LEFTARG = regclass,
3537
    RIGHTARG = text
3538
);
3539

    
3540

    
3541
--
3542
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3543
--
3544

    
3545
CREATE OPERATOR => (
3546
    PROCEDURE = hstore,
3547
    LEFTARG = text[],
3548
    RIGHTARG = text
3549
);
3550

    
3551

    
3552
--
3553
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3554
--
3555

    
3556
COMMENT ON OPERATOR => (text[], text) IS '
3557
usage: array[''key1'', ...]::text[] => ''value''
3558
';
3559

    
3560

    
3561
--
3562
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3563
--
3564

    
3565
CREATE OPERATOR ?*>= (
3566
    PROCEDURE = is_populated_more_often_than,
3567
    LEFTARG = anyelement,
3568
    RIGHTARG = anyelement
3569
);
3570

    
3571

    
3572
--
3573
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3574
--
3575

    
3576
CREATE OPERATOR ?>= (
3577
    PROCEDURE = is_more_complete_than,
3578
    LEFTARG = anyelement,
3579
    RIGHTARG = anyelement
3580
);
3581

    
3582

    
3583
--
3584
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3585
--
3586

    
3587
CREATE OPERATOR ||% (
3588
    PROCEDURE = concat_esc,
3589
    LEFTARG = text,
3590
    RIGHTARG = text
3591
);
3592

    
3593

    
3594
--
3595
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3596
--
3597

    
3598
COMMENT ON OPERATOR ||% (text, text) IS '
3599
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3600
';
3601

    
3602

    
3603
--
3604
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3605
--
3606

    
3607
CREATE TABLE map (
3608
    "from" text NOT NULL,
3609
    "to" text,
3610
    filter text,
3611
    notes text
3612
);
3613

    
3614

    
3615
--
3616
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3617
--
3618

    
3619

    
3620

    
3621
--
3622
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3623
--
3624

    
3625

    
3626

    
3627
--
3628
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3629
--
3630

    
3631
ALTER TABLE ONLY map
3632
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3633

    
3634

    
3635
--
3636
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3637
--
3638

    
3639
ALTER TABLE ONLY map
3640
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3641

    
3642

    
3643
--
3644
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3645
--
3646

    
3647
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3648

    
3649

    
3650
--
3651
-- PostgreSQL database dump complete
3652
--
3653

    
(19-19/29)