Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

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

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

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

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

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

    
84

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

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

    
93

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

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

    
104

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

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

    
124

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

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

    
133

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

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

    
153

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

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

    
172

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

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

    
190

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

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

    
201

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

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

    
212

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

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

    
225

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

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

    
236

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

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

    
247

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

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

    
258

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

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

    
269

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

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

    
280

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

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

    
291

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

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

    
306

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

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

    
331

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

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

    
342

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

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

    
381

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

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

    
392

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

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

    
431

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

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

    
442

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

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

    
453

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

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

    
464

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

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

    
475

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

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

    
501

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

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

    
521

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

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

    
530

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

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

    
541

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

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

    
552

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

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

    
570

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

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

    
579

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

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

    
590

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

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

    
607

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

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

    
618

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

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

    
629

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

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

    
638

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

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

    
649

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

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

    
660

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

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

    
671

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

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

    
680

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

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

    
691

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

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

    
707

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

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

    
716

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

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

    
732

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

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

    
756

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

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

    
779

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

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

    
790

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

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

    
799

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

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

    
815

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

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

    
832

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

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

    
846

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

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

    
859

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

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

    
882

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

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

    
893

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

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

    
904

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

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

    
915

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

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

    
926

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

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

    
947

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

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

    
956

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

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

    
967

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

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

    
980

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

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

    
995

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

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

    
1011

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

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

    
1020

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

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

    
1033

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

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

    
1044

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

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

    
1073

    
1074
--
1075
-- 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: -
1076
--
1077

    
1078
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 '
1079
col_type_null (*required*): NULL::col_type
1080
single_row: whether the tables consist of a single row, which should be
1081
	displayed side-by-side
1082

    
1083
to run EXPLAIN on the FULL JOIN query:
1084
# run this function
1085
# look for a NOTICE containing the expanded query that it ran
1086
# run EXPLAIN on this expanded query
1087
';
1088

    
1089

    
1090
--
1091
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1092
--
1093

    
1094
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1095
    LANGUAGE sql
1096
    AS $_$
1097
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1098
$_$;
1099

    
1100

    
1101
--
1102
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1103
--
1104

    
1105
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1106
idempotent
1107
';
1108

    
1109

    
1110
--
1111
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1112
--
1113

    
1114
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1115
    LANGUAGE sql
1116
    AS $_$
1117
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1118
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1119
$_$;
1120

    
1121

    
1122
--
1123
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1124
--
1125

    
1126
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1127
idempotent
1128
';
1129

    
1130

    
1131
--
1132
-- Name: drop_relation(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
1133
--
1134

    
1135
CREATE FUNCTION drop_relation(relation regclass, force boolean DEFAULT false) RETURNS void
1136
    LANGUAGE sql
1137
    AS $_$
1138
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1139
included in the debug SQL */
1140
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1141
$_$;
1142

    
1143

    
1144
--
1145
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1146
--
1147

    
1148
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1149
    LANGUAGE sql
1150
    AS $_$
1151
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1152
||util._if($3, $$ CASCADE$$, ''::text))
1153
$_$;
1154

    
1155

    
1156
--
1157
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1158
--
1159

    
1160
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1161
idempotent
1162
';
1163

    
1164

    
1165
--
1166
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1167
--
1168

    
1169
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1170
    LANGUAGE sql
1171
    AS $_$
1172
SELECT util.drop_relations_like($1, util.str_equality_regexp(util.schema($2)),
1173
$3)
1174
$_$;
1175

    
1176

    
1177
--
1178
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1179
--
1180

    
1181
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1182
    LANGUAGE sql
1183
    AS $_$
1184
SELECT util.drop_relation(relation, $3)
1185
FROM util.show_relations_like($1, $2) relation
1186
;
1187
SELECT NULL::void; -- don't fold away functions called in previous query
1188
$_$;
1189

    
1190

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

    
1195
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1196
    LANGUAGE sql
1197
    AS $_$
1198
SELECT util.drop_relation('TABLE', $1, $2)
1199
$_$;
1200

    
1201

    
1202
--
1203
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1204
--
1205

    
1206
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1207
idempotent
1208
';
1209

    
1210

    
1211
--
1212
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1213
--
1214

    
1215
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1216
    LANGUAGE sql
1217
    AS $_$
1218
SELECT util.drop_relation('VIEW', $1, $2)
1219
$_$;
1220

    
1221

    
1222
--
1223
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1224
--
1225

    
1226
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1227
idempotent
1228
';
1229

    
1230

    
1231
--
1232
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1233
--
1234

    
1235
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1236
    LANGUAGE sql IMMUTABLE
1237
    AS $_$
1238
SELECT util.array_fill($1, 0)
1239
$_$;
1240

    
1241

    
1242
--
1243
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1244
--
1245

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

    
1250

    
1251
--
1252
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1253
--
1254

    
1255
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1256
    LANGUAGE sql IMMUTABLE
1257
    AS $_$
1258
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1259
$_$;
1260

    
1261

    
1262
--
1263
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1264
--
1265

    
1266
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1267
    LANGUAGE sql IMMUTABLE
1268
    AS $_$
1269
SELECT regexp_replace($2, '("?)$', $1||'\1')
1270
$_$;
1271

    
1272

    
1273
--
1274
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1275
--
1276

    
1277
CREATE FUNCTION eval(sql text) RETURNS void
1278
    LANGUAGE plpgsql STRICT
1279
    AS $$
1280
BEGIN
1281
	PERFORM util.debug_print_sql(sql);
1282
	EXECUTE sql;
1283
END;
1284
$$;
1285

    
1286

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

    
1291
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1292
    LANGUAGE plpgsql
1293
    AS $$
1294
BEGIN
1295
	PERFORM util.debug_print_sql(sql);
1296
	RETURN QUERY EXECUTE sql;
1297
END;
1298
$$;
1299

    
1300

    
1301
--
1302
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1303
--
1304

    
1305
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1306
col_type_null (*required*): NULL::col_type
1307
';
1308

    
1309

    
1310
--
1311
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1312
--
1313

    
1314
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1315
    LANGUAGE plpgsql
1316
    AS $$
1317
BEGIN
1318
	PERFORM util.debug_print_sql(sql);
1319
	RETURN QUERY EXECUTE sql;
1320
END;
1321
$$;
1322

    
1323

    
1324
--
1325
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1326
--
1327

    
1328
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1329
    LANGUAGE plpgsql
1330
    AS $$
1331
BEGIN
1332
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1333
	RETURN QUERY EXECUTE sql;
1334
END;
1335
$$;
1336

    
1337

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

    
1342
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1343
    LANGUAGE plpgsql
1344
    AS $$
1345
DECLARE
1346
	ret_val ret_type_null%TYPE;
1347
BEGIN
1348
	PERFORM util.debug_print_sql(sql);
1349
	EXECUTE sql INTO STRICT ret_val;
1350
	RETURN ret_val;
1351
END;
1352
$$;
1353

    
1354

    
1355
--
1356
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1357
--
1358

    
1359
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1360
ret_type_null: NULL::ret_type
1361
';
1362

    
1363

    
1364
--
1365
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1366
--
1367

    
1368
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1369
    LANGUAGE sql
1370
    AS $_$
1371
SELECT util.eval2val($$SELECT $$||$1, $2)
1372
$_$;
1373

    
1374

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

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

    
1383

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

    
1388
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1389
    LANGUAGE sql
1390
    AS $_$
1391
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1392
$_$;
1393

    
1394

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

    
1399
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1400
sql: can be NULL, which will be passed through
1401
ret_type_null: NULL::ret_type
1402
';
1403

    
1404

    
1405
--
1406
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1407
--
1408

    
1409
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1410
    LANGUAGE sql STABLE
1411
    AS $_$
1412
SELECT col_name
1413
FROM unnest($2) s (col_name)
1414
WHERE util.col_exists(($1, col_name))
1415
$_$;
1416

    
1417

    
1418
--
1419
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1420
--
1421

    
1422
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1423
    LANGUAGE sql
1424
    AS $_$
1425
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1426
$_$;
1427

    
1428

    
1429
--
1430
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1431
--
1432

    
1433
CREATE FUNCTION explain2notice(sql text) RETURNS void
1434
    LANGUAGE sql
1435
    AS $_$
1436
SELECT util.raise_notice(util.explain2notice_msg($1))
1437
$_$;
1438

    
1439

    
1440
--
1441
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1442
--
1443

    
1444
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1445
    LANGUAGE sql
1446
    AS $_$
1447
-- newline before and after to visually separate it from other debug info
1448
SELECT $$
1449
EXPLAIN:
1450
$$||util.explain2str($1)||$$
1451
$$
1452
$_$;
1453

    
1454

    
1455
--
1456
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1457
--
1458

    
1459
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1460
    LANGUAGE sql
1461
    AS $_$
1462
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1463
$_$;
1464

    
1465

    
1466
--
1467
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1468
--
1469

    
1470
CREATE FUNCTION explain2str(sql text) RETURNS text
1471
    LANGUAGE sql
1472
    AS $_$
1473
SELECT util.join_strs(explain, $$
1474
$$) FROM util.explain($1)
1475
$_$;
1476

    
1477

    
1478
SET default_tablespace = '';
1479

    
1480
SET default_with_oids = false;
1481

    
1482
--
1483
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1484
--
1485

    
1486
CREATE TABLE explain (
1487
    line text NOT NULL
1488
);
1489

    
1490

    
1491
--
1492
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1493
--
1494

    
1495
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1496
    LANGUAGE sql
1497
    AS $_$
1498
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1499
$$||quote_nullable($1)||$$
1500
)$$)
1501
$_$;
1502

    
1503

    
1504
--
1505
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1506
--
1507

    
1508
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1509
usage:
1510
PERFORM util.explain2table($$
1511
query
1512
$$);
1513
';
1514

    
1515

    
1516
--
1517
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1518
--
1519

    
1520
CREATE FUNCTION first_word(str text) RETURNS text
1521
    LANGUAGE sql IMMUTABLE
1522
    AS $_$
1523
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1524
$_$;
1525

    
1526

    
1527
--
1528
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1529
--
1530

    
1531
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1532
    LANGUAGE sql IMMUTABLE
1533
    AS $_$
1534
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1535
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1536
) END
1537
$_$;
1538

    
1539

    
1540
--
1541
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1542
--
1543

    
1544
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1545
ensures that an array will always have proper non-NULL dimensions
1546
';
1547

    
1548

    
1549
--
1550
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1551
--
1552

    
1553
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1554
    LANGUAGE plpgsql
1555
    AS $_$
1556
DECLARE
1557
	PG_EXCEPTION_DETAIL text;
1558
	recreate_users_cmd text = util.save_drop_views(users);
1559
BEGIN
1560
	PERFORM util.eval(cmd);
1561
	PERFORM util.eval(recreate_users_cmd);
1562
EXCEPTION
1563
WHEN dependent_objects_still_exist THEN
1564
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1565
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1566
	users = array(SELECT * FROM util.regexp_matches_group(
1567
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1568
	IF util.is_empty(users) THEN RAISE; END IF;
1569
	PERFORM util.force_recreate(cmd, users);
1570
END;
1571
$_$;
1572

    
1573

    
1574
--
1575
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1576
--
1577

    
1578
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1579
idempotent
1580

    
1581
users: not necessary to provide this because it will be autopopulated
1582
';
1583

    
1584

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

    
1589
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1590
    LANGUAGE plpgsql STRICT
1591
    AS $_$
1592
DECLARE
1593
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1594
$$||query;
1595
BEGIN
1596
	EXECUTE mk_view;
1597
EXCEPTION
1598
WHEN invalid_table_definition THEN
1599
	IF SQLERRM = 'cannot drop columns from view'
1600
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1601
	THEN
1602
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1603
		EXECUTE mk_view;
1604
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1605
	END IF;
1606
END;
1607
$_$;
1608

    
1609

    
1610
--
1611
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1612
--
1613

    
1614
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1615
idempotent
1616
';
1617

    
1618

    
1619
--
1620
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1621
--
1622

    
1623
CREATE FUNCTION grants_users() RETURNS SETOF text
1624
    LANGUAGE sql IMMUTABLE
1625
    AS $$
1626
VALUES ('bien_read'), ('public_')
1627
$$;
1628

    
1629

    
1630
--
1631
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1632
--
1633

    
1634
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1635
    LANGUAGE sql IMMUTABLE
1636
    AS $_$
1637
SELECT substring($2 for length($1)) = $1
1638
$_$;
1639

    
1640

    
1641
--
1642
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1643
--
1644

    
1645
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1646
    LANGUAGE sql STABLE
1647
    AS $_$
1648
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1649
$_$;
1650

    
1651

    
1652
--
1653
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1654
--
1655

    
1656
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1657
    LANGUAGE sql IMMUTABLE
1658
    AS $_$
1659
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1660
$_$;
1661

    
1662

    
1663
--
1664
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1665
--
1666

    
1667
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1668
avoids repeating the same value for each key
1669
';
1670

    
1671

    
1672
--
1673
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1674
--
1675

    
1676
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1677
    LANGUAGE sql IMMUTABLE
1678
    AS $_$
1679
SELECT COALESCE($1, $2)
1680
$_$;
1681

    
1682

    
1683
--
1684
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1685
--
1686

    
1687
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1688
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1689
';
1690

    
1691

    
1692
--
1693
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1694
--
1695

    
1696
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1697
    LANGUAGE sql
1698
    AS $_$
1699
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1700
$_$;
1701

    
1702

    
1703
--
1704
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1705
--
1706

    
1707
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1708
    LANGUAGE sql STABLE
1709
    AS $_$
1710
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1711
$_$;
1712

    
1713

    
1714
--
1715
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1716
--
1717

    
1718
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1719
    LANGUAGE sql IMMUTABLE
1720
    AS $_$
1721
SELECT util.array_length($1) = 0
1722
$_$;
1723

    
1724

    
1725
--
1726
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1727
--
1728

    
1729
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1730
    LANGUAGE sql IMMUTABLE
1731
    AS $_$
1732
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1733
$_$;
1734

    
1735

    
1736
--
1737
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1738
--
1739

    
1740
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1741
    LANGUAGE sql IMMUTABLE
1742
    AS $_$
1743
SELECT upper(util.first_word($1)) = ANY(
1744
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1745
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1746
)
1747
$_$;
1748

    
1749

    
1750
--
1751
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1752
--
1753

    
1754
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1755
    LANGUAGE sql IMMUTABLE
1756
    AS $_$
1757
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1758
$_$;
1759

    
1760

    
1761
--
1762
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1763
--
1764

    
1765
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1766
    LANGUAGE sql IMMUTABLE
1767
    AS $_$
1768
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1769
$_$;
1770

    
1771

    
1772
--
1773
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1774
--
1775

    
1776
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1777
    LANGUAGE sql STABLE
1778
    AS $_$
1779
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1780
$_$;
1781

    
1782

    
1783
--
1784
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1785
--
1786

    
1787
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1788
    LANGUAGE sql STABLE
1789
    AS $_$
1790
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1791
$_$;
1792

    
1793

    
1794
--
1795
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1796
--
1797

    
1798
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1799
    LANGUAGE sql IMMUTABLE STRICT
1800
    AS $_$
1801
SELECT $1 || $3 || $2
1802
$_$;
1803

    
1804

    
1805
--
1806
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1807
--
1808

    
1809
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1810
must be declared STRICT to use the special handling of STRICT aggregating functions
1811
';
1812

    
1813

    
1814
--
1815
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1816
--
1817

    
1818
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1819
    LANGUAGE sql IMMUTABLE
1820
    AS $_$
1821
SELECT $1 -- compare on the entire value
1822
$_$;
1823

    
1824

    
1825
--
1826
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1827
--
1828

    
1829
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1830
    LANGUAGE sql IMMUTABLE
1831
    AS $_$
1832
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1833
$_$;
1834

    
1835

    
1836
--
1837
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1838
--
1839

    
1840
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1841
    LANGUAGE sql IMMUTABLE
1842
    AS $_$
1843
SELECT ltrim($1, $$
1844
$$)
1845
$_$;
1846

    
1847

    
1848
--
1849
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1850
--
1851

    
1852
CREATE FUNCTION map_filter_insert() RETURNS trigger
1853
    LANGUAGE plpgsql
1854
    AS $$
1855
BEGIN
1856
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1857
	RETURN new;
1858
END;
1859
$$;
1860

    
1861

    
1862
--
1863
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1864
--
1865

    
1866
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1867
    LANGUAGE plpgsql STABLE STRICT
1868
    AS $_$
1869
DECLARE
1870
    value text;
1871
BEGIN
1872
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1873
        INTO value USING key;
1874
    RETURN value;
1875
END;
1876
$_$;
1877

    
1878

    
1879
--
1880
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1881
--
1882

    
1883
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1884
    LANGUAGE sql IMMUTABLE
1885
    AS $_$
1886
SELECT util._map(util.nulls_map($1), $2)
1887
$_$;
1888

    
1889

    
1890
--
1891
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1892
--
1893

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

    
1897
[1] inlining of function calls, which is different from constant folding
1898
[2] _map()''s profiling query
1899
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1900
and map_nulls()''s profiling query
1901
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1902
both take ~920 ms.
1903
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.
1904
';
1905

    
1906

    
1907
--
1908
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1909
--
1910

    
1911
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1912
    LANGUAGE plpgsql STABLE STRICT
1913
    AS $_$
1914
BEGIN
1915
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1916
END;
1917
$_$;
1918

    
1919

    
1920
--
1921
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1922
--
1923

    
1924
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1925
    LANGUAGE sql
1926
    AS $_$
1927
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1928
$$||util.ltrim_nl($2));
1929
-- make sure the created table has the correct estimated row count
1930
SELECT util.analyze_($1);
1931

    
1932
SELECT util.append_comment($1, '
1933
contents generated from:
1934
'||util.ltrim_nl($2)||';
1935
');
1936
$_$;
1937

    
1938

    
1939
--
1940
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1941
--
1942

    
1943
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1944
idempotent
1945
';
1946

    
1947

    
1948
--
1949
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1950
--
1951

    
1952
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1953
    LANGUAGE sql
1954
    AS $_$
1955
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1956
$_$;
1957

    
1958

    
1959
--
1960
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1961
--
1962

    
1963
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1964
idempotent
1965
';
1966

    
1967

    
1968
--
1969
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1970
--
1971

    
1972
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1973
    LANGUAGE sql
1974
    AS $_$
1975
SELECT util.create_if_not_exists($$
1976
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1977
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1978
||quote_literal($2)||$$;
1979
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1980
constant
1981
';
1982
$$)
1983
$_$;
1984

    
1985

    
1986
--
1987
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1988
--
1989

    
1990
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1991
idempotent
1992
';
1993

    
1994

    
1995
--
1996
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1997
--
1998

    
1999
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2000
    LANGUAGE plpgsql STRICT
2001
    AS $_$
2002
DECLARE
2003
    type regtype = util.typeof(expr, col.table_::text::regtype);
2004
    col_name_sql text = quote_ident(col.name);
2005
BEGIN
2006
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2007
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2008
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2009
$$||expr||$$;
2010
$$);
2011
END;
2012
$_$;
2013

    
2014

    
2015
--
2016
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2017
--
2018

    
2019
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2020
idempotent
2021
';
2022

    
2023

    
2024
--
2025
-- Name: mk_diff_query(text, text, boolean, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2026
--
2027

    
2028
CREATE FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean DEFAULT false, cols text DEFAULT 'left_, right_'::text, join_cond text DEFAULT 'left_ %== right_ -- refer to EXPLAIN output for expansion of %=='::text, filter text DEFAULT 'left_ IS DISTINCT FROM right_'::text) RETURNS text
2029
    LANGUAGE sql IMMUTABLE
2030
    AS $_$
2031
SELECT
2032
$$SELECT
2033
$$||$4||$$
2034
FROM $$||$1||$$ left_
2035
$$||util._if($3, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
2036
$$||util._if($3, ''::text,
2037
$$ON $$||$5||$$
2038
$$)||
2039
$$WHERE $$||$6||$$
2040
ORDER BY left_, right_
2041
$$
2042
$_$;
2043

    
2044

    
2045
--
2046
-- Name: FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean, cols text, join_cond text, filter text); Type: COMMENT; Schema: util; Owner: -
2047
--
2048

    
2049
COMMENT ON FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean, cols text, join_cond text, filter text) IS '
2050
single_row: whether the tables consist of a single row, which should be
2051
	displayed side-by-side
2052
';
2053

    
2054

    
2055
--
2056
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2057
--
2058

    
2059
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2060
    LANGUAGE sql
2061
    AS $_$
2062
SELECT util.create_if_not_exists($$
2063
CREATE TABLE $$||$1||$$
2064
(
2065
    LIKE util.map INCLUDING ALL
2066
);
2067

    
2068
CREATE TRIGGER map_filter_insert
2069
  BEFORE INSERT
2070
  ON $$||$1||$$
2071
  FOR EACH ROW
2072
  EXECUTE PROCEDURE util.map_filter_insert();
2073
$$)
2074
$_$;
2075

    
2076

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

    
2081
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2082
    LANGUAGE sql IMMUTABLE
2083
    AS $_$
2084
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
2085
$_$;
2086

    
2087

    
2088
--
2089
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2090
--
2091

    
2092
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
2093
    LANGUAGE sql IMMUTABLE
2094
    AS $_$
2095
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
2096
$_$;
2097

    
2098

    
2099
--
2100
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2101
--
2102

    
2103
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
2104
usage:
2105
for *1* schema arg:
2106
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
2107
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2108
';
2109

    
2110

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

    
2115
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2116
    LANGUAGE sql IMMUTABLE
2117
    AS $_$
2118
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2119
$_$;
2120

    
2121

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

    
2126
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2127
    LANGUAGE sql IMMUTABLE
2128
    AS $_$
2129
/* debug_print_return_value() needed because this function is used with EXECUTE
2130
rather than util.eval() (in order to affect the calling function), so the
2131
search_path would not otherwise be printed */
2132
SELECT util.debug_print_return_value($$SET$$
2133
||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$) ||$$ search_path TO $$||$1)
2134
$_$;
2135

    
2136

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

    
2141
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2142
    LANGUAGE sql
2143
    AS $_$
2144
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2145
$_$;
2146

    
2147

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

    
2152
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2153
idempotent
2154
';
2155

    
2156

    
2157
--
2158
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2159
--
2160

    
2161
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2162
    LANGUAGE plpgsql STRICT
2163
    AS $_$
2164
DECLARE
2165
	view_qual_name text = util.qual_name(view_);
2166
BEGIN
2167
	EXECUTE $$
2168
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2169
  RETURNS SETOF $$||view_||$$ AS
2170
$BODY1$
2171
SELECT * FROM $$||view_qual_name||$$
2172
ORDER BY sort_col
2173
LIMIT $1 OFFSET $2
2174
$BODY1$
2175
  LANGUAGE sql STABLE
2176
  COST 100
2177
  ROWS 1000
2178
$$;
2179
	
2180
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2181
END;
2182
$_$;
2183

    
2184

    
2185
--
2186
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2187
--
2188

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

    
2228

    
2229
--
2230
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2231
--
2232

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

    
2261

    
2262
--
2263
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2264
--
2265

    
2266
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2267
creates subset function which turns off enable_sort
2268
';
2269

    
2270

    
2271
--
2272
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2273
--
2274

    
2275
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2276
    LANGUAGE sql IMMUTABLE
2277
    AS $_$
2278
SELECT util.mk_set_search_path(util.schema_esc($1))
2279
$_$;
2280

    
2281

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

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

    
2292

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

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

    
2303

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

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

    
2314

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

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

    
2325

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

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

    
2336

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

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

    
2347

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

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

    
2358

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

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

    
2367

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

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

    
2378

    
2379
--
2380
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2381
--
2382

    
2383
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2384
    LANGUAGE sql IMMUTABLE
2385
    AS $_$
2386
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2387
$_$;
2388

    
2389

    
2390
--
2391
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2392
--
2393

    
2394
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2395
    LANGUAGE sql STABLE
2396
    SET search_path TO pg_temp
2397
    AS $_$
2398
SELECT $1::text
2399
$_$;
2400

    
2401

    
2402
--
2403
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2404
--
2405

    
2406
CREATE FUNCTION qual_name(type regtype) RETURNS text
2407
    LANGUAGE sql STABLE
2408
    SET search_path TO pg_temp
2409
    AS $_$
2410
SELECT $1::text
2411
$_$;
2412

    
2413

    
2414
--
2415
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2416
--
2417

    
2418
COMMENT ON FUNCTION qual_name(type regtype) IS '
2419
a type''s schema-qualified name
2420
';
2421

    
2422

    
2423
--
2424
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2425
--
2426

    
2427
CREATE FUNCTION qual_name(type unknown) RETURNS text
2428
    LANGUAGE sql STABLE
2429
    AS $_$
2430
SELECT util.qual_name($1::text::regtype)
2431
$_$;
2432

    
2433

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

    
2438
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2439
    LANGUAGE sql IMMUTABLE
2440
    AS $_$
2441
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2442
$_$;
2443

    
2444

    
2445
--
2446
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2447
--
2448

    
2449
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2450
    LANGUAGE sql IMMUTABLE
2451
    AS $_$
2452
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2453
$_$;
2454

    
2455

    
2456
--
2457
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2458
--
2459

    
2460
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2461
    LANGUAGE sql IMMUTABLE
2462
    AS $_$
2463
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2464
$_$;
2465

    
2466

    
2467
--
2468
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2469
--
2470

    
2471
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2472
    LANGUAGE sql IMMUTABLE
2473
    AS $_$
2474
SELECT util.raise_notice('ERROR:  '||$1)
2475
$_$;
2476

    
2477

    
2478
--
2479
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2480
--
2481

    
2482
CREATE FUNCTION raise_notice(msg text) RETURNS void
2483
    LANGUAGE plpgsql IMMUTABLE STRICT
2484
    AS $$
2485
BEGIN
2486
	RAISE NOTICE '%', msg;
2487
END;
2488
$$;
2489

    
2490

    
2491
--
2492
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2493
--
2494

    
2495
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2496
    LANGUAGE plpgsql IMMUTABLE STRICT
2497
    AS $$
2498
BEGIN
2499
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2500
END;
2501
$$;
2502

    
2503

    
2504
--
2505
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2506
--
2507

    
2508
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2509
    LANGUAGE sql IMMUTABLE
2510
    AS $_$
2511
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2512
$_$;
2513

    
2514

    
2515
--
2516
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2517
--
2518

    
2519
CREATE FUNCTION regexp_quote(str text) RETURNS text
2520
    LANGUAGE sql IMMUTABLE
2521
    AS $_$
2522
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2523
$_$;
2524

    
2525

    
2526
--
2527
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2528
--
2529

    
2530
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2531
    LANGUAGE sql IMMUTABLE
2532
    AS $_$
2533
SELECT (CASE WHEN right($1, 1) = ')'
2534
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2535
$_$;
2536

    
2537

    
2538
--
2539
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2540
--
2541

    
2542
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2543
    LANGUAGE sql STABLE
2544
    AS $_$
2545
SELECT util.relation_type(util.relation_type_char($1))
2546
$_$;
2547

    
2548

    
2549
--
2550
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2551
--
2552

    
2553
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2554
    LANGUAGE sql IMMUTABLE
2555
    AS $_$
2556
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2557
$_$;
2558

    
2559

    
2560
--
2561
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2562
--
2563

    
2564
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2565
    LANGUAGE sql STABLE
2566
    AS $_$
2567
SELECT relkind FROM pg_class WHERE oid = $1
2568
$_$;
2569

    
2570

    
2571
--
2572
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2573
--
2574

    
2575
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2576
    LANGUAGE sql
2577
    AS $_$
2578
/* can't have in_table/out_table inherit from *each other*, because inheritance
2579
also causes the rows of the parent table to be included in the child table.
2580
instead, they need to inherit from a common, empty table. */
2581
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2582
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2583
SELECT util.inherit($2, $4);
2584
SELECT util.inherit($3, $4);
2585

    
2586
SELECT util.rematerialize_query($1, $$
2587
SELECT * FROM util.diff(
2588
  $$||util.quote_typed($2)||$$
2589
, $$||util.quote_typed($3)||$$
2590
, NULL::$$||$4||$$)
2591
$$);
2592

    
2593
/* the table unfortunately cannot be *materialized* in human-readable form,
2594
because this would create column name collisions between the two sides */
2595
SELECT util.append_comment($1, '
2596
to view this table in human-readable form (with each side''s tuple column
2597
expanded to its component fields):
2598
SELECT (left_).*, (right_).* FROM '||$1||';
2599
');
2600
$_$;
2601

    
2602

    
2603
--
2604
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2605
--
2606

    
2607
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2608
type_table (*required*): table to create as the shared base type
2609
';
2610

    
2611

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

    
2616
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2617
    LANGUAGE sql
2618
    AS $_$
2619
SELECT util.drop_table($1);
2620
SELECT util.materialize_query($1, $2);
2621
$_$;
2622

    
2623

    
2624
--
2625
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2626
--
2627

    
2628
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2629
idempotent, but repeats action each time
2630
';
2631

    
2632

    
2633
--
2634
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2635
--
2636

    
2637
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2638
    LANGUAGE sql
2639
    AS $_$
2640
SELECT util.drop_table($1);
2641
SELECT util.materialize_view($1, $2);
2642
$_$;
2643

    
2644

    
2645
--
2646
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2647
--
2648

    
2649
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2650
idempotent, but repeats action each time
2651
';
2652

    
2653

    
2654
--
2655
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2656
--
2657

    
2658
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2659
    LANGUAGE sql
2660
    AS $_$
2661
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2662
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2663
FROM util.col_names($1::text::regtype) f (name);
2664
SELECT NULL::void; -- don't fold away functions called in previous query
2665
$_$;
2666

    
2667

    
2668
--
2669
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2670
--
2671

    
2672
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2673
idempotent
2674
';
2675

    
2676

    
2677
--
2678
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2679
--
2680

    
2681
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2682
    LANGUAGE sql
2683
    AS $_$
2684
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2685
included in the debug SQL */
2686
SELECT util.rename_relation(util.qual_name($1), $2)
2687
$_$;
2688

    
2689

    
2690
--
2691
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2692
--
2693

    
2694
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2695
    LANGUAGE sql
2696
    AS $_$
2697
/* 'ALTER TABLE can be used with views too'
2698
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2699
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2700
||quote_ident($2))
2701
$_$;
2702

    
2703

    
2704
--
2705
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2706
--
2707

    
2708
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2709
idempotent
2710
';
2711

    
2712

    
2713
--
2714
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2715
--
2716

    
2717
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2718
    LANGUAGE sql IMMUTABLE
2719
    AS $_$
2720
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2721
$_$;
2722

    
2723

    
2724
--
2725
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2726
--
2727

    
2728
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2729
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 
2730
';
2731

    
2732

    
2733
--
2734
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2735
--
2736

    
2737
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2738
    LANGUAGE sql
2739
    AS $_$
2740
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2741
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2742
SELECT util.set_col_names($1, $2);
2743
$_$;
2744

    
2745

    
2746
--
2747
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2748
--
2749

    
2750
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2751
idempotent.
2752
alters the names table, so it will need to be repopulated after running this function.
2753
';
2754

    
2755

    
2756
--
2757
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2758
--
2759

    
2760
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2761
    LANGUAGE sql
2762
    AS $_$
2763
SELECT util.drop_table($1);
2764
SELECT util.mk_map_table($1);
2765
$_$;
2766

    
2767

    
2768
--
2769
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2770
--
2771

    
2772
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2773
    LANGUAGE sql IMMUTABLE
2774
    AS $_$
2775
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2776
$_$;
2777

    
2778

    
2779
--
2780
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
2781
--
2782

    
2783
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2784
    LANGUAGE sql IMMUTABLE
2785
    AS $_$
2786
SELECT util.mk_set_search_path(for_printing := true)||$$;
2787
$$||$1
2788
$_$;
2789

    
2790

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

    
2795
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2796
    LANGUAGE plpgsql STRICT
2797
    AS $_$
2798
DECLARE
2799
	result text = NULL;
2800
BEGIN
2801
	BEGIN
2802
		result = util.show_create_view(view_);
2803
		PERFORM util.eval($$DROP VIEW $$||view_);
2804
	EXCEPTION
2805
		WHEN undefined_table THEN NULL;
2806
	END;
2807
	RETURN result;
2808
END;
2809
$_$;
2810

    
2811

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

    
2816
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2817
    LANGUAGE sql
2818
    AS $_$
2819
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2820
$_$;
2821

    
2822

    
2823
--
2824
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2825
--
2826

    
2827
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2828
    LANGUAGE sql STABLE
2829
    AS $_$
2830
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2831
$_$;
2832

    
2833

    
2834
--
2835
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2836
--
2837

    
2838
CREATE FUNCTION schema(table_ regclass) RETURNS text
2839
    LANGUAGE sql STABLE
2840
    AS $_$
2841
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2842
$_$;
2843

    
2844

    
2845
--
2846
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2847
--
2848

    
2849
CREATE FUNCTION schema(type regtype) RETURNS text
2850
    LANGUAGE sql STABLE
2851
    AS $_$
2852
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2853
$_$;
2854

    
2855

    
2856
--
2857
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2858
--
2859

    
2860
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2861
    LANGUAGE sql STABLE
2862
    AS $_$
2863
SELECT util.schema(pg_typeof($1))
2864
$_$;
2865

    
2866

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

    
2871
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2872
    LANGUAGE sql STABLE
2873
    AS $_$
2874
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2875
$_$;
2876

    
2877

    
2878
--
2879
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2880
--
2881

    
2882
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2883
a schema bundle is a group of schemas with a common prefix
2884
';
2885

    
2886

    
2887
--
2888
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2889
--
2890

    
2891
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2892
    LANGUAGE sql
2893
    AS $_$
2894
SELECT util.schema_rename(old_schema,
2895
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2896
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2897
SELECT NULL::void; -- don't fold away functions called in previous query
2898
$_$;
2899

    
2900

    
2901
--
2902
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2903
--
2904

    
2905
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2906
    LANGUAGE plpgsql
2907
    AS $$
2908
BEGIN
2909
	-- don't schema_bundle_rm() the schema_bundle to keep!
2910
	IF replace = with_ THEN RETURN; END IF;
2911
	
2912
	PERFORM util.schema_bundle_rm(replace);
2913
	PERFORM util.schema_bundle_rename(with_, replace);
2914
END;
2915
$$;
2916

    
2917

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

    
2922
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2923
    LANGUAGE sql
2924
    AS $_$
2925
SELECT util.schema_rm(schema)
2926
FROM util.schema_bundle_get_schemas($1) f (schema);
2927
SELECT NULL::void; -- don't fold away functions called in previous query
2928
$_$;
2929

    
2930

    
2931
--
2932
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2933
--
2934

    
2935
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2936
    LANGUAGE sql STABLE
2937
    AS $_$
2938
SELECT quote_ident(util.schema($1))
2939
$_$;
2940

    
2941

    
2942
--
2943
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2944
--
2945

    
2946
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2947
    LANGUAGE sql IMMUTABLE
2948
    AS $_$
2949
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2950
$_$;
2951

    
2952

    
2953
--
2954
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2955
--
2956

    
2957
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2958
    LANGUAGE sql STABLE
2959
    AS $_$
2960
SELECT oid FROM pg_namespace WHERE nspname = $1
2961
$_$;
2962

    
2963

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

    
2968
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2969
    LANGUAGE sql
2970
    AS $_$
2971
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2972
$_$;
2973

    
2974

    
2975
--
2976
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2977
--
2978

    
2979
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2980
    LANGUAGE plpgsql
2981
    AS $$
2982
BEGIN
2983
	-- don't schema_rm() the schema to keep!
2984
	IF replace = with_ THEN RETURN; END IF;
2985
	
2986
	PERFORM util.schema_rm(replace);
2987
	PERFORM util.schema_rename(with_, replace);
2988
END;
2989
$$;
2990

    
2991

    
2992
--
2993
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2994
--
2995

    
2996
CREATE FUNCTION schema_rm(schema text) RETURNS void
2997
    LANGUAGE sql
2998
    AS $_$
2999
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3000
$_$;
3001

    
3002

    
3003
--
3004
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3005
--
3006

    
3007
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3008
    LANGUAGE sql
3009
    AS $_$
3010
SELECT util.eval(
3011
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3012
$_$;
3013

    
3014

    
3015
--
3016
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3017
--
3018

    
3019
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3020
    LANGUAGE plpgsql STRICT
3021
    AS $_$
3022
DECLARE
3023
    old text[] = ARRAY(SELECT util.col_names(table_));
3024
    new text[] = ARRAY(SELECT util.map_values(names));
3025
BEGIN
3026
    old = old[1:array_length(new, 1)]; -- truncate to same length
3027
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3028
||$$ TO $$||quote_ident(value))
3029
    FROM each(hstore(old, new))
3030
    WHERE value != key -- not same name
3031
    ;
3032
END;
3033
$_$;
3034

    
3035

    
3036
--
3037
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3038
--
3039

    
3040
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3041
idempotent
3042
';
3043

    
3044

    
3045
--
3046
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3047
--
3048

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

    
3076

    
3077
--
3078
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3079
--
3080

    
3081
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3082
idempotent.
3083
the metadata mappings must be *last* in the names table.
3084
';
3085

    
3086

    
3087
--
3088
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3089
--
3090

    
3091
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3092
    LANGUAGE plpgsql STRICT
3093
    AS $_$
3094
DECLARE
3095
    sql text = $$ALTER TABLE $$||table_||$$
3096
$$||NULLIF(array_to_string(ARRAY(
3097
    SELECT
3098
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3099
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3100
    FROM
3101
    (
3102
        SELECT
3103
          quote_ident(col_name) AS col_name_sql
3104
        , util.col_type((table_, col_name)) AS curr_type
3105
        , type AS target_type
3106
        FROM unnest(col_casts)
3107
    ) s
3108
    WHERE curr_type != target_type
3109
), '
3110
, '), '');
3111
BEGIN
3112
    PERFORM util.debug_print_sql(sql);
3113
    EXECUTE COALESCE(sql, '');
3114
END;
3115
$_$;
3116

    
3117

    
3118
--
3119
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3120
--
3121

    
3122
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3123
idempotent
3124
';
3125

    
3126

    
3127
--
3128
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3129
--
3130

    
3131
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3132
    LANGUAGE sql
3133
    AS $_$
3134
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3135
$_$;
3136

    
3137

    
3138
--
3139
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3140
--
3141

    
3142
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3143
    LANGUAGE sql STABLE
3144
    AS $_$
3145
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3146
$$||util.show_grants_for($1)
3147
$_$;
3148

    
3149

    
3150
--
3151
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3152
--
3153

    
3154
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3155
    LANGUAGE sql STABLE
3156
    AS $_$
3157
SELECT string_agg(cmd, '')
3158
FROM
3159
(
3160
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3161
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3162
$$ ELSE '' END) AS cmd
3163
	FROM util.grants_users() f (user_)
3164
) s
3165
$_$;
3166

    
3167

    
3168
--
3169
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3170
--
3171

    
3172
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3173
    LANGUAGE sql STABLE
3174
    AS $_$
3175
SELECT oid FROM pg_class
3176
WHERE relkind = ANY($3) AND relname ~ $1
3177
AND util.schema_matches(util.schema(relnamespace), $2)
3178
ORDER BY relname
3179
$_$;
3180

    
3181

    
3182
--
3183
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3184
--
3185

    
3186
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3187
    LANGUAGE sql STABLE
3188
    AS $_$
3189
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3190
$_$;
3191

    
3192

    
3193
--
3194
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3195
--
3196

    
3197
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3198
    LANGUAGE sql IMMUTABLE
3199
    AS $_$
3200
SELECT '^'||util.regexp_quote($1)||'$'
3201
$_$;
3202

    
3203

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

    
3208
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3209
    LANGUAGE plpgsql STABLE STRICT
3210
    AS $_$
3211
DECLARE
3212
    hstore hstore;
3213
BEGIN
3214
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3215
        table_||$$))$$ INTO STRICT hstore;
3216
    RETURN hstore;
3217
END;
3218
$_$;
3219

    
3220

    
3221
--
3222
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3223
--
3224

    
3225
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3226
    LANGUAGE sql STABLE
3227
    AS $_$
3228
SELECT COUNT(*) > 0 FROM pg_constraint
3229
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3230
$_$;
3231

    
3232

    
3233
--
3234
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3235
--
3236

    
3237
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3238
gets whether a status flag is set by the presence of a table constraint
3239
';
3240

    
3241

    
3242
--
3243
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3244
--
3245

    
3246
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3247
    LANGUAGE sql
3248
    AS $_$
3249
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3250
||quote_ident($2)||$$ CHECK (true)$$)
3251
$_$;
3252

    
3253

    
3254
--
3255
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3256
--
3257

    
3258
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3259
stores a status flag by the presence of a table constraint.
3260
idempotent.
3261
';
3262

    
3263

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

    
3268
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3269
    LANGUAGE sql STABLE
3270
    AS $_$
3271
SELECT util.table_flag__get($1, 'nulls_mapped')
3272
$_$;
3273

    
3274

    
3275
--
3276
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3277
--
3278

    
3279
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3280
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3281
';
3282

    
3283

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

    
3288
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3289
    LANGUAGE sql
3290
    AS $_$
3291
SELECT util.table_flag__set($1, 'nulls_mapped')
3292
$_$;
3293

    
3294

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

    
3299
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3300
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3301
idempotent.
3302
';
3303

    
3304

    
3305
--
3306
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3307
--
3308

    
3309
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3310
    LANGUAGE plpgsql STRICT
3311
    AS $_$
3312
DECLARE
3313
    row record;
3314
BEGIN
3315
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3316
    LOOP
3317
        IF row.global_name != row.name THEN
3318
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3319
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3320
        END IF;
3321
    END LOOP;
3322
END;
3323
$_$;
3324

    
3325

    
3326
--
3327
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3328
--
3329

    
3330
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3331
idempotent
3332
';
3333

    
3334

    
3335
--
3336
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3337
--
3338

    
3339
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3340
    LANGUAGE sql
3341
    AS $_$
3342
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3343
SELECT NULL::void; -- don't fold away functions called in previous query
3344
$_$;
3345

    
3346

    
3347
--
3348
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3349
--
3350

    
3351
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3352
trims table_ to include only columns in the original data.
3353
idempotent.
3354
';
3355

    
3356

    
3357
--
3358
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3359
--
3360

    
3361
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3362
    LANGUAGE plpgsql STRICT
3363
    AS $_$
3364
BEGIN
3365
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3366
END;
3367
$_$;
3368

    
3369

    
3370
--
3371
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3372
--
3373

    
3374
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3375
idempotent
3376
';
3377

    
3378

    
3379
--
3380
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3381
--
3382

    
3383
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3384
    LANGUAGE sql IMMUTABLE
3385
    AS $_$
3386
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3387
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3388
$_$;
3389

    
3390

    
3391
--
3392
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3393
--
3394

    
3395
CREATE FUNCTION try_create(sql text) RETURNS void
3396
    LANGUAGE plpgsql STRICT
3397
    AS $$
3398
BEGIN
3399
    PERFORM util.eval(sql);
3400
EXCEPTION
3401
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3402
    WHEN undefined_column THEN NULL;
3403
    WHEN duplicate_column THEN NULL;
3404
END;
3405
$$;
3406

    
3407

    
3408
--
3409
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3410
--
3411

    
3412
COMMENT ON FUNCTION try_create(sql text) IS '
3413
idempotent
3414
';
3415

    
3416

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

    
3421
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3422
    LANGUAGE sql
3423
    AS $_$
3424
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3425
$_$;
3426

    
3427

    
3428
--
3429
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3430
--
3431

    
3432
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3433
idempotent
3434
';
3435

    
3436

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

    
3441
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3442
    LANGUAGE sql IMMUTABLE
3443
    AS $_$
3444
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3445
$_$;
3446

    
3447

    
3448
--
3449
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3450
--
3451

    
3452
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3453
a type''s NOT NULL qualifier
3454
';
3455

    
3456

    
3457
--
3458
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3459
--
3460

    
3461
CREATE FUNCTION typeof(value anyelement) RETURNS text
3462
    LANGUAGE sql IMMUTABLE
3463
    AS $_$
3464
SELECT util.qual_name(pg_typeof($1))
3465
$_$;
3466

    
3467

    
3468
--
3469
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3470
--
3471

    
3472
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3473
    LANGUAGE plpgsql STABLE
3474
    AS $_$
3475
DECLARE
3476
    type regtype;
3477
BEGIN
3478
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3479
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3480
    RETURN type;
3481
END;
3482
$_$;
3483

    
3484

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

    
3489
CREATE AGGREGATE all_same(anyelement) (
3490
    SFUNC = all_same_transform,
3491
    STYPE = anyarray,
3492
    FINALFUNC = all_same_final
3493
);
3494

    
3495

    
3496
--
3497
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3498
--
3499

    
3500
COMMENT ON AGGREGATE all_same(anyelement) IS '
3501
includes NULLs in comparison
3502
';
3503

    
3504

    
3505
--
3506
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3507
--
3508

    
3509
CREATE AGGREGATE join_strs(text, text) (
3510
    SFUNC = join_strs_transform,
3511
    STYPE = text
3512
);
3513

    
3514

    
3515
--
3516
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3517
--
3518

    
3519
CREATE OPERATOR %== (
3520
    PROCEDURE = "%==",
3521
    LEFTARG = anyelement,
3522
    RIGHTARG = anyelement
3523
);
3524

    
3525

    
3526
--
3527
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3528
--
3529

    
3530
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3531
returns whether the map-keys of the compared values are the same
3532
(mnemonic: % is the Perl symbol for a hash map)
3533

    
3534
should be overridden for types that store both keys and values
3535

    
3536
used in a FULL JOIN to select which columns to join on
3537
';
3538

    
3539

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

    
3544
CREATE OPERATOR -> (
3545
    PROCEDURE = map_get,
3546
    LEFTARG = regclass,
3547
    RIGHTARG = text
3548
);
3549

    
3550

    
3551
--
3552
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3553
--
3554

    
3555
CREATE OPERATOR => (
3556
    PROCEDURE = hstore,
3557
    LEFTARG = text[],
3558
    RIGHTARG = text
3559
);
3560

    
3561

    
3562
--
3563
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3564
--
3565

    
3566
COMMENT ON OPERATOR => (text[], text) IS '
3567
usage: array[''key1'', ...]::text[] => ''value''
3568
';
3569

    
3570

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

    
3575
CREATE OPERATOR ?*>= (
3576
    PROCEDURE = is_populated_more_often_than,
3577
    LEFTARG = anyelement,
3578
    RIGHTARG = anyelement
3579
);
3580

    
3581

    
3582
--
3583
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3584
--
3585

    
3586
CREATE OPERATOR ?>= (
3587
    PROCEDURE = is_more_complete_than,
3588
    LEFTARG = anyelement,
3589
    RIGHTARG = anyelement
3590
);
3591

    
3592

    
3593
--
3594
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3595
--
3596

    
3597
CREATE OPERATOR ||% (
3598
    PROCEDURE = concat_esc,
3599
    LEFTARG = text,
3600
    RIGHTARG = text
3601
);
3602

    
3603

    
3604
--
3605
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3606
--
3607

    
3608
COMMENT ON OPERATOR ||% (text, text) IS '
3609
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3610
';
3611

    
3612

    
3613
--
3614
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3615
--
3616

    
3617
CREATE TABLE map (
3618
    "from" text NOT NULL,
3619
    "to" text,
3620
    filter text,
3621
    notes text
3622
);
3623

    
3624

    
3625
--
3626
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3627
--
3628

    
3629

    
3630

    
3631
--
3632
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3633
--
3634

    
3635

    
3636

    
3637
--
3638
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3639
--
3640

    
3641
ALTER TABLE ONLY map
3642
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3643

    
3644

    
3645
--
3646
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3647
--
3648

    
3649
ALTER TABLE ONLY map
3650
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3651

    
3652

    
3653
--
3654
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3655
--
3656

    
3657
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3658

    
3659

    
3660
--
3661
-- PostgreSQL database dump complete
3662
--
3663

    
(19-19/29)