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

    
997

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

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

    
1013

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

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

    
1022

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

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

    
1035

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

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

    
1046

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

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

    
1083

    
1084
--
1085
-- 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: -
1086
--
1087

    
1088
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 '
1089
col_type_null (*required*): NULL::col_type
1090
single_row: whether the tables consist of a single row, which should be
1091
	displayed side-by-side
1092

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

    
1099

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

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

    
1110

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

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

    
1119

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

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

    
1131

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

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

    
1140

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

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

    
1153

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

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

    
1165

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

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

    
1174

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

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

    
1186

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

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

    
1200

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

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

    
1211

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

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

    
1220

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

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

    
1231

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

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

    
1240

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

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

    
1251

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

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

    
1260

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

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

    
1271

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

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

    
1282

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

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

    
1296

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

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

    
1310

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

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

    
1319

    
1320
--
1321
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1322
--
1323

    
1324
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1325
    LANGUAGE plpgsql
1326
    AS $$
1327
BEGIN
1328
	PERFORM util.debug_print_sql(sql);
1329
	RETURN QUERY EXECUTE sql;
1330
END;
1331
$$;
1332

    
1333

    
1334
--
1335
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1336
--
1337

    
1338
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1339
    LANGUAGE plpgsql
1340
    AS $$
1341
BEGIN
1342
	PERFORM util.debug_print_sql(sql);
1343
	RETURN QUERY EXECUTE sql;
1344
END;
1345
$$;
1346

    
1347

    
1348
--
1349
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1350
--
1351

    
1352
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1353
ret_type_null: NULL::ret_type
1354
';
1355

    
1356

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

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

    
1373

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

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

    
1382

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

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

    
1393

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

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

    
1402

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

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

    
1413

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

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

    
1423

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

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

    
1436

    
1437
--
1438
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1439
--
1440

    
1441
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1442
    LANGUAGE sql
1443
    AS $_$
1444
SELECT util.eval2set($$EXPLAIN $$||$1)
1445
$_$;
1446

    
1447

    
1448
--
1449
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1450
--
1451

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

    
1458

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

    
1463
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1464
    LANGUAGE sql
1465
    AS $_$
1466
SELECT $$EXPLAIN:
1467
$$||util.explain2str($1)
1468
$_$;
1469

    
1470

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

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

    
1481

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

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

    
1493

    
1494
SET default_tablespace = '';
1495

    
1496
SET default_with_oids = false;
1497

    
1498
--
1499
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1500
--
1501

    
1502
CREATE TABLE explain (
1503
    line text NOT NULL
1504
);
1505

    
1506

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

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

    
1519

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

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

    
1531

    
1532
--
1533
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1534
--
1535

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

    
1542

    
1543
--
1544
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1545
--
1546

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

    
1555

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

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

    
1564

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

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

    
1589

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

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

    
1597
users: not necessary to provide this because it will be autopopulated
1598
';
1599

    
1600

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

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

    
1625

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

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

    
1634

    
1635
--
1636
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1637
--
1638

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

    
1645

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

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

    
1656

    
1657
--
1658
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1659
--
1660

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

    
1667

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

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

    
1678

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

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

    
1687

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

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

    
1698

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

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

    
1707

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

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

    
1718

    
1719
--
1720
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1721
--
1722

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

    
1729

    
1730
--
1731
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1732
--
1733

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

    
1740

    
1741
--
1742
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1743
--
1744

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

    
1754

    
1755
--
1756
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1757
--
1758

    
1759
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1760
    LANGUAGE sql IMMUTABLE
1761
    AS $_$
1762
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1763
$_$;
1764

    
1765

    
1766
--
1767
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1768
--
1769

    
1770
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1771
    LANGUAGE sql IMMUTABLE
1772
    AS $_$
1773
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1774
$_$;
1775

    
1776

    
1777
--
1778
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1779
--
1780

    
1781
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1782
    LANGUAGE sql STABLE
1783
    AS $_$
1784
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1785
$_$;
1786

    
1787

    
1788
--
1789
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1790
--
1791

    
1792
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1793
    LANGUAGE sql STABLE
1794
    AS $_$
1795
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1796
$_$;
1797

    
1798

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

    
1803
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1804
    LANGUAGE sql IMMUTABLE STRICT
1805
    AS $_$
1806
SELECT $1 || $3 || $2
1807
$_$;
1808

    
1809

    
1810
--
1811
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1812
--
1813

    
1814
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1815
must be declared STRICT to use the special handling of STRICT aggregating functions
1816
';
1817

    
1818

    
1819
--
1820
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1821
--
1822

    
1823
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1824
    LANGUAGE sql IMMUTABLE
1825
    AS $_$
1826
SELECT $1 -- compare on the entire value
1827
$_$;
1828

    
1829

    
1830
--
1831
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1832
--
1833

    
1834
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1835
    LANGUAGE sql IMMUTABLE
1836
    AS $_$
1837
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1838
$_$;
1839

    
1840

    
1841
--
1842
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1843
--
1844

    
1845
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1846
    LANGUAGE sql IMMUTABLE
1847
    AS $_$
1848
SELECT ltrim($1, $$
1849
$$)
1850
$_$;
1851

    
1852

    
1853
--
1854
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856

    
1857
CREATE FUNCTION map_filter_insert() RETURNS trigger
1858
    LANGUAGE plpgsql
1859
    AS $$
1860
BEGIN
1861
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1862
	RETURN new;
1863
END;
1864
$$;
1865

    
1866

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

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

    
1883

    
1884
--
1885
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1886
--
1887

    
1888
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1889
    LANGUAGE sql IMMUTABLE
1890
    AS $_$
1891
SELECT util._map(util.nulls_map($1), $2)
1892
$_$;
1893

    
1894

    
1895
--
1896
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1897
--
1898

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

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

    
1911

    
1912
--
1913
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1914
--
1915

    
1916
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1917
    LANGUAGE plpgsql STABLE STRICT
1918
    AS $_$
1919
BEGIN
1920
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1921
END;
1922
$_$;
1923

    
1924

    
1925
--
1926
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1927
--
1928

    
1929
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1930
    LANGUAGE sql
1931
    AS $_$
1932
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1933
$$||util.ltrim_nl($2));
1934
-- make sure the created table has the correct estimated row count
1935
SELECT util.analyze_($1);
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_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2026
--
2027

    
2028
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2029
    LANGUAGE sql
2030
    AS $_$
2031
SELECT util.create_if_not_exists($$
2032
CREATE TABLE $$||$1||$$
2033
(
2034
    LIKE util.map INCLUDING ALL
2035
);
2036

    
2037
CREATE TRIGGER map_filter_insert
2038
  BEFORE INSERT
2039
  ON $$||$1||$$
2040
  FOR EACH ROW
2041
  EXECUTE PROCEDURE util.map_filter_insert();
2042
$$)
2043
$_$;
2044

    
2045

    
2046
--
2047
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2048
--
2049

    
2050
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2051
    LANGUAGE sql IMMUTABLE
2052
    AS $_$
2053
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
2054
$_$;
2055

    
2056

    
2057
--
2058
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2059
--
2060

    
2061
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
2062
    LANGUAGE sql IMMUTABLE
2063
    AS $_$
2064
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
2065
$_$;
2066

    
2067

    
2068
--
2069
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2070
--
2071

    
2072
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
2073
usage:
2074
for *1* schema arg:
2075
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
2076
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2077
';
2078

    
2079

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

    
2084
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
2085
    LANGUAGE sql IMMUTABLE
2086
    AS $_$
2087
/* debug_print_return_value() needed because this function is used with EXECUTE
2088
rather than util.eval() (in order to affect the calling function), so the
2089
search_path would not otherwise be printed */
2090
SELECT util.debug_print_return_value($$SET LOCAL search_path TO $$||$1)
2091
$_$;
2092

    
2093

    
2094
--
2095
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2096
--
2097

    
2098
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2099
    LANGUAGE sql
2100
    AS $_$
2101
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2102
$_$;
2103

    
2104

    
2105
--
2106
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2107
--
2108

    
2109
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2110
idempotent
2111
';
2112

    
2113

    
2114
--
2115
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2116
--
2117

    
2118
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2119
    LANGUAGE plpgsql STRICT
2120
    AS $_$
2121
DECLARE
2122
	view_qual_name text = util.qual_name(view_);
2123
BEGIN
2124
	EXECUTE $$
2125
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2126
  RETURNS SETOF $$||view_||$$ AS
2127
$BODY1$
2128
SELECT * FROM $$||view_qual_name||$$
2129
ORDER BY sort_col
2130
LIMIT $1 OFFSET $2
2131
$BODY1$
2132
  LANGUAGE sql STABLE
2133
  COST 100
2134
  ROWS 1000
2135
$$;
2136
	
2137
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2138
END;
2139
$_$;
2140

    
2141

    
2142
--
2143
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2144
--
2145

    
2146
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2147
    LANGUAGE plpgsql STRICT
2148
    AS $_$
2149
DECLARE
2150
	view_qual_name text = util.qual_name(view_);
2151
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2152
BEGIN
2153
	EXECUTE $$
2154
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2155
  RETURNS integer AS
2156
$BODY1$
2157
SELECT $$||quote_ident(row_num_col)||$$
2158
FROM $$||view_qual_name||$$
2159
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2160
LIMIT 1
2161
$BODY1$
2162
  LANGUAGE sql STABLE
2163
  COST 100;
2164
$$;
2165
	
2166
	EXECUTE $$
2167
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2168
  RETURNS SETOF $$||view_||$$ AS
2169
$BODY1$
2170
SELECT * FROM $$||view_qual_name||$$
2171
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2172
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2173
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2174
ORDER BY $$||quote_ident(row_num_col)||$$
2175
$BODY1$
2176
  LANGUAGE sql STABLE
2177
  COST 100
2178
  ROWS 1000
2179
$$;
2180
	
2181
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2182
END;
2183
$_$;
2184

    
2185

    
2186
--
2187
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2188
--
2189

    
2190
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2191
    LANGUAGE plpgsql STRICT
2192
    AS $_$
2193
DECLARE
2194
	view_qual_name text = util.qual_name(view_);
2195
BEGIN
2196
	EXECUTE $$
2197
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2198
  RETURNS SETOF $$||view_||$$
2199
  SET enable_sort TO 'off'
2200
  AS
2201
$BODY1$
2202
SELECT * FROM $$||view_qual_name||$$($2, $3)
2203
$BODY1$
2204
  LANGUAGE sql STABLE
2205
  COST 100
2206
  ROWS 1000
2207
;
2208
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2209
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2210
If you want to run EXPLAIN and get expanded output, use the regular subset
2211
function instead. (When a config param is set on a function, EXPLAIN produces
2212
just a function scan.)
2213
';
2214
$$;
2215
END;
2216
$_$;
2217

    
2218

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

    
2223
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2224
creates subset function which turns off enable_sort
2225
';
2226

    
2227

    
2228
--
2229
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2230
--
2231

    
2232
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2233
    LANGUAGE sql IMMUTABLE
2234
    AS $_$
2235
SELECT util.mk_set_search_path(util.schema_esc($1))
2236
$_$;
2237

    
2238

    
2239
--
2240
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2241
--
2242

    
2243
CREATE FUNCTION name(table_ regclass) RETURNS text
2244
    LANGUAGE sql STABLE
2245
    AS $_$
2246
SELECT relname::text FROM pg_class WHERE oid = $1
2247
$_$;
2248

    
2249

    
2250
--
2251
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2252
--
2253

    
2254
CREATE FUNCTION name(type regtype) RETURNS text
2255
    LANGUAGE sql STABLE
2256
    AS $_$
2257
SELECT typname::text FROM pg_type WHERE oid = $1
2258
$_$;
2259

    
2260

    
2261
--
2262
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2263
--
2264

    
2265
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2266
    LANGUAGE sql IMMUTABLE
2267
    AS $_$
2268
SELECT octet_length($1) >= util.namedatalen() - $2
2269
$_$;
2270

    
2271

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

    
2276
CREATE FUNCTION namedatalen() RETURNS integer
2277
    LANGUAGE sql IMMUTABLE
2278
    AS $$
2279
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2280
$$;
2281

    
2282

    
2283
--
2284
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2285
--
2286

    
2287
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2288
    LANGUAGE sql IMMUTABLE
2289
    AS $_$
2290
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2291
$_$;
2292

    
2293

    
2294
--
2295
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2296
--
2297

    
2298
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2299
    LANGUAGE sql IMMUTABLE
2300
    AS $_$
2301
SELECT $1 IS NOT NULL
2302
$_$;
2303

    
2304

    
2305
--
2306
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2307
--
2308

    
2309
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2310
    LANGUAGE sql IMMUTABLE
2311
    AS $_$
2312
SELECT util.hstore($1, NULL) || '*=>*'
2313
$_$;
2314

    
2315

    
2316
--
2317
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2318
--
2319

    
2320
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2321
for use with _map()
2322
';
2323

    
2324

    
2325
--
2326
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2327
--
2328

    
2329
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2330
    LANGUAGE sql IMMUTABLE
2331
    AS $_$
2332
SELECT $2 + COALESCE($1, 0)
2333
$_$;
2334

    
2335

    
2336
--
2337
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2338
--
2339

    
2340
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2341
    LANGUAGE sql IMMUTABLE
2342
    AS $_$
2343
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2344
$_$;
2345

    
2346

    
2347
--
2348
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2349
--
2350

    
2351
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2352
    LANGUAGE sql STABLE
2353
    SET search_path TO pg_temp
2354
    AS $_$
2355
SELECT $1::text
2356
$_$;
2357

    
2358

    
2359
--
2360
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2361
--
2362

    
2363
CREATE FUNCTION qual_name(type regtype) RETURNS text
2364
    LANGUAGE sql STABLE
2365
    SET search_path TO pg_temp
2366
    AS $_$
2367
SELECT $1::text
2368
$_$;
2369

    
2370

    
2371
--
2372
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2373
--
2374

    
2375
COMMENT ON FUNCTION qual_name(type regtype) IS '
2376
a type''s schema-qualified name
2377
';
2378

    
2379

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

    
2384
CREATE FUNCTION qual_name(type unknown) RETURNS text
2385
    LANGUAGE sql STABLE
2386
    AS $_$
2387
SELECT util.qual_name($1::text::regtype)
2388
$_$;
2389

    
2390

    
2391
--
2392
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2393
--
2394

    
2395
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2396
    LANGUAGE sql IMMUTABLE
2397
    AS $_$
2398
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2399
$_$;
2400

    
2401

    
2402
--
2403
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2404
--
2405

    
2406
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2407
    LANGUAGE sql IMMUTABLE
2408
    AS $_$
2409
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2410
$_$;
2411

    
2412

    
2413
--
2414
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2415
--
2416

    
2417
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2418
    LANGUAGE sql IMMUTABLE
2419
    AS $_$
2420
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2421
$_$;
2422

    
2423

    
2424
--
2425
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2426
--
2427

    
2428
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2429
    LANGUAGE sql IMMUTABLE
2430
    AS $_$
2431
SELECT util.raise_notice('ERROR:  '||$1)
2432
$_$;
2433

    
2434

    
2435
--
2436
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2437
--
2438

    
2439
CREATE FUNCTION raise_notice(msg text) RETURNS void
2440
    LANGUAGE plpgsql IMMUTABLE STRICT
2441
    AS $$
2442
BEGIN
2443
	RAISE NOTICE '%', msg;
2444
END;
2445
$$;
2446

    
2447

    
2448
--
2449
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2450
--
2451

    
2452
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2453
    LANGUAGE plpgsql IMMUTABLE STRICT
2454
    AS $$
2455
BEGIN
2456
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2457
END;
2458
$$;
2459

    
2460

    
2461
--
2462
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2463
--
2464

    
2465
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2466
    LANGUAGE sql IMMUTABLE
2467
    AS $_$
2468
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2469
$_$;
2470

    
2471

    
2472
--
2473
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2474
--
2475

    
2476
CREATE FUNCTION regexp_quote(str text) RETURNS text
2477
    LANGUAGE sql IMMUTABLE
2478
    AS $_$
2479
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2480
$_$;
2481

    
2482

    
2483
--
2484
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2485
--
2486

    
2487
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2488
    LANGUAGE sql IMMUTABLE
2489
    AS $_$
2490
SELECT (CASE WHEN right($1, 1) = ')'
2491
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2492
$_$;
2493

    
2494

    
2495
--
2496
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2497
--
2498

    
2499
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2500
    LANGUAGE sql STABLE
2501
    AS $_$
2502
SELECT util.relation_type(util.relation_type_char($1))
2503
$_$;
2504

    
2505

    
2506
--
2507
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2508
--
2509

    
2510
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2511
    LANGUAGE sql IMMUTABLE
2512
    AS $_$
2513
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2514
$_$;
2515

    
2516

    
2517
--
2518
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2519
--
2520

    
2521
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2522
    LANGUAGE sql STABLE
2523
    AS $_$
2524
SELECT relkind FROM pg_class WHERE oid = $1
2525
$_$;
2526

    
2527

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

    
2532
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2533
    LANGUAGE sql
2534
    AS $_$
2535
/* can't have in_table/out_table inherit from *each other*, because inheritance
2536
also causes the rows of the parent table to be included in the child table.
2537
instead, they need to inherit from a common, empty table. */
2538
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2539
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2540
SELECT util.inherit($2, $4);
2541
SELECT util.inherit($3, $4);
2542

    
2543
SELECT util.rematerialize_query($1, $$
2544
SELECT * FROM util.diff(
2545
  $$||util.quote_typed($2)||$$
2546
, $$||util.quote_typed($3)||$$
2547
, NULL::$$||$4||$$)
2548
$$);
2549

    
2550
/* the table unfortunately cannot be *materialized* in human-readable form,
2551
because this would create column name collisions between the two sides */
2552
SELECT util.append_comment($1, '
2553
to view this table in human-readable form (with each side''s tuple column
2554
expanded to its component fields):
2555
SELECT (left_).*, (right_).* FROM '||$1||';
2556
');
2557
$_$;
2558

    
2559

    
2560
--
2561
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2562
--
2563

    
2564
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2565
type_table (*required*): table to create as the shared base type
2566
';
2567

    
2568

    
2569
--
2570
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2571
--
2572

    
2573
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2574
    LANGUAGE sql
2575
    AS $_$
2576
SELECT util.drop_table($1);
2577
SELECT util.materialize_query($1, $2);
2578
$_$;
2579

    
2580

    
2581
--
2582
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2583
--
2584

    
2585
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2586
idempotent, but repeats action each time
2587
';
2588

    
2589

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

    
2594
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2595
    LANGUAGE sql
2596
    AS $_$
2597
SELECT util.drop_table($1);
2598
SELECT util.materialize_view($1, $2);
2599
$_$;
2600

    
2601

    
2602
--
2603
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2604
--
2605

    
2606
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2607
idempotent, but repeats action each time
2608
';
2609

    
2610

    
2611
--
2612
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2613
--
2614

    
2615
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2616
    LANGUAGE sql
2617
    AS $_$
2618
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2619
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2620
FROM util.col_names($1::text::regtype) f (name);
2621
SELECT NULL::void; -- don't fold away functions called in previous query
2622
$_$;
2623

    
2624

    
2625
--
2626
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2627
--
2628

    
2629
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2630
idempotent
2631
';
2632

    
2633

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

    
2638
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2639
    LANGUAGE sql
2640
    AS $_$
2641
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2642
included in the debug SQL */
2643
SELECT util.rename_relation(util.qual_name($1), $2)
2644
$_$;
2645

    
2646

    
2647
--
2648
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2649
--
2650

    
2651
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2652
    LANGUAGE sql
2653
    AS $_$
2654
/* 'ALTER TABLE can be used with views too'
2655
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2656
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2657
||quote_ident($2))
2658
$_$;
2659

    
2660

    
2661
--
2662
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2663
--
2664

    
2665
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2666
idempotent
2667
';
2668

    
2669

    
2670
--
2671
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2672
--
2673

    
2674
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2675
    LANGUAGE sql IMMUTABLE
2676
    AS $_$
2677
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2678
$_$;
2679

    
2680

    
2681
--
2682
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2683
--
2684

    
2685
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2686
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 
2687
';
2688

    
2689

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

    
2694
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2695
    LANGUAGE sql
2696
    AS $_$
2697
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2698
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2699
SELECT util.set_col_names($1, $2);
2700
$_$;
2701

    
2702

    
2703
--
2704
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2705
--
2706

    
2707
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2708
idempotent.
2709
alters the names table, so it will need to be repopulated after running this function.
2710
';
2711

    
2712

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

    
2717
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2718
    LANGUAGE sql
2719
    AS $_$
2720
SELECT util.drop_table($1);
2721
SELECT util.mk_map_table($1);
2722
$_$;
2723

    
2724

    
2725
--
2726
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2727
--
2728

    
2729
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2730
    LANGUAGE sql IMMUTABLE
2731
    AS $_$
2732
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2733
$_$;
2734

    
2735

    
2736
--
2737
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2738
--
2739

    
2740
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2741
    LANGUAGE plpgsql STRICT
2742
    AS $_$
2743
DECLARE
2744
	result text = NULL;
2745
BEGIN
2746
	BEGIN
2747
		result = util.show_create_view(view_);
2748
		PERFORM util.eval($$DROP VIEW $$||view_);
2749
	EXCEPTION
2750
		WHEN undefined_table THEN NULL;
2751
	END;
2752
	RETURN result;
2753
END;
2754
$_$;
2755

    
2756

    
2757
--
2758
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2759
--
2760

    
2761
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2762
    LANGUAGE sql
2763
    AS $_$
2764
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2765
$_$;
2766

    
2767

    
2768
--
2769
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2770
--
2771

    
2772
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2773
    LANGUAGE sql STABLE
2774
    AS $_$
2775
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2776
$_$;
2777

    
2778

    
2779
--
2780
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2781
--
2782

    
2783
CREATE FUNCTION schema(table_ regclass) RETURNS text
2784
    LANGUAGE sql STABLE
2785
    AS $_$
2786
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2787
$_$;
2788

    
2789

    
2790
--
2791
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2792
--
2793

    
2794
CREATE FUNCTION schema(type regtype) RETURNS text
2795
    LANGUAGE sql STABLE
2796
    AS $_$
2797
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2798
$_$;
2799

    
2800

    
2801
--
2802
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2803
--
2804

    
2805
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2806
    LANGUAGE sql STABLE
2807
    AS $_$
2808
SELECT util.schema(pg_typeof($1))
2809
$_$;
2810

    
2811

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

    
2816
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2817
    LANGUAGE sql STABLE
2818
    AS $_$
2819
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2820
$_$;
2821

    
2822

    
2823
--
2824
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2825
--
2826

    
2827
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2828
a schema bundle is a group of schemas with a common prefix
2829
';
2830

    
2831

    
2832
--
2833
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2834
--
2835

    
2836
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2837
    LANGUAGE sql
2838
    AS $_$
2839
SELECT util.schema_rename(old_schema,
2840
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2841
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2842
SELECT NULL::void; -- don't fold away functions called in previous query
2843
$_$;
2844

    
2845

    
2846
--
2847
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2848
--
2849

    
2850
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2851
    LANGUAGE plpgsql
2852
    AS $$
2853
BEGIN
2854
	-- don't schema_bundle_rm() the schema_bundle to keep!
2855
	IF replace = with_ THEN RETURN; END IF;
2856
	
2857
	PERFORM util.schema_bundle_rm(replace);
2858
	PERFORM util.schema_bundle_rename(with_, replace);
2859
END;
2860
$$;
2861

    
2862

    
2863
--
2864
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2865
--
2866

    
2867
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2868
    LANGUAGE sql
2869
    AS $_$
2870
SELECT util.schema_rm(schema)
2871
FROM util.schema_bundle_get_schemas($1) f (schema);
2872
SELECT NULL::void; -- don't fold away functions called in previous query
2873
$_$;
2874

    
2875

    
2876
--
2877
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2878
--
2879

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

    
2886

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

    
2891
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2892
    LANGUAGE sql IMMUTABLE
2893
    AS $_$
2894
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2895
$_$;
2896

    
2897

    
2898
--
2899
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2900
--
2901

    
2902
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2903
    LANGUAGE sql STABLE
2904
    AS $_$
2905
SELECT oid FROM pg_namespace WHERE nspname = $1
2906
$_$;
2907

    
2908

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

    
2913
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2914
    LANGUAGE sql
2915
    AS $_$
2916
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2917
$_$;
2918

    
2919

    
2920
--
2921
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2922
--
2923

    
2924
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2925
    LANGUAGE plpgsql
2926
    AS $$
2927
BEGIN
2928
	-- don't schema_rm() the schema to keep!
2929
	IF replace = with_ THEN RETURN; END IF;
2930
	
2931
	PERFORM util.schema_rm(replace);
2932
	PERFORM util.schema_rename(with_, replace);
2933
END;
2934
$$;
2935

    
2936

    
2937
--
2938
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2939
--
2940

    
2941
CREATE FUNCTION schema_rm(schema text) RETURNS void
2942
    LANGUAGE sql
2943
    AS $_$
2944
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2945
$_$;
2946

    
2947

    
2948
--
2949
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2950
--
2951

    
2952
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2953
    LANGUAGE sql
2954
    AS $_$
2955
SELECT util.eval(
2956
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2957
$_$;
2958

    
2959

    
2960
--
2961
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2962
--
2963

    
2964
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2965
    LANGUAGE plpgsql STRICT
2966
    AS $_$
2967
DECLARE
2968
    old text[] = ARRAY(SELECT util.col_names(table_));
2969
    new text[] = ARRAY(SELECT util.map_values(names));
2970
BEGIN
2971
    old = old[1:array_length(new, 1)]; -- truncate to same length
2972
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2973
||$$ TO $$||quote_ident(value))
2974
    FROM each(hstore(old, new))
2975
    WHERE value != key -- not same name
2976
    ;
2977
END;
2978
$_$;
2979

    
2980

    
2981
--
2982
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2983
--
2984

    
2985
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2986
idempotent
2987
';
2988

    
2989

    
2990
--
2991
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2992
--
2993

    
2994
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2995
    LANGUAGE plpgsql STRICT
2996
    AS $_$
2997
DECLARE
2998
	row_ util.map;
2999
BEGIN
3000
	-- rename any metadata cols rather than re-adding them with new names
3001
	BEGIN
3002
		PERFORM util.set_col_names(table_, names);
3003
	EXCEPTION
3004
		WHEN array_subscript_error THEN -- selective suppress
3005
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3006
				-- metadata cols not yet added
3007
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
3008
			END IF;
3009
	END;
3010
	
3011
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3012
	LOOP
3013
		PERFORM util.mk_const_col((table_, row_."to"),
3014
			substring(row_."from" from 2));
3015
	END LOOP;
3016
	
3017
	PERFORM util.set_col_names(table_, names);
3018
END;
3019
$_$;
3020

    
3021

    
3022
--
3023
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3024
--
3025

    
3026
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3027
idempotent.
3028
the metadata mappings must be *last* in the names table.
3029
';
3030

    
3031

    
3032
--
3033
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3034
--
3035

    
3036
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3037
    LANGUAGE plpgsql STRICT
3038
    AS $_$
3039
DECLARE
3040
    sql text = $$ALTER TABLE $$||table_||$$
3041
$$||NULLIF(array_to_string(ARRAY(
3042
    SELECT
3043
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3044
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3045
    FROM
3046
    (
3047
        SELECT
3048
          quote_ident(col_name) AS col_name_sql
3049
        , util.col_type((table_, col_name)) AS curr_type
3050
        , type AS target_type
3051
        FROM unnest(col_casts)
3052
    ) s
3053
    WHERE curr_type != target_type
3054
), '
3055
, '), '');
3056
BEGIN
3057
    PERFORM util.debug_print_sql(sql);
3058
    EXECUTE COALESCE(sql, '');
3059
END;
3060
$_$;
3061

    
3062

    
3063
--
3064
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3065
--
3066

    
3067
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3068
idempotent
3069
';
3070

    
3071

    
3072
--
3073
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3074
--
3075

    
3076
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3077
    LANGUAGE sql
3078
    AS $_$
3079
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3080
$_$;
3081

    
3082

    
3083
--
3084
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3085
--
3086

    
3087
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3088
    LANGUAGE sql STABLE
3089
    AS $_$
3090
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3091
$$||util.show_grants_for($1)
3092
$_$;
3093

    
3094

    
3095
--
3096
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3097
--
3098

    
3099
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3100
    LANGUAGE sql STABLE
3101
    AS $_$
3102
SELECT string_agg(cmd, '')
3103
FROM
3104
(
3105
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3106
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3107
$$ ELSE '' END) AS cmd
3108
	FROM util.grants_users() f (user_)
3109
) s
3110
$_$;
3111

    
3112

    
3113
--
3114
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3115
--
3116

    
3117
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3118
    LANGUAGE sql STABLE
3119
    AS $_$
3120
SELECT oid FROM pg_class
3121
WHERE relkind = ANY($3) AND relname ~ $1
3122
AND util.schema_matches(util.schema(relnamespace), $2)
3123
ORDER BY relname
3124
$_$;
3125

    
3126

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

    
3131
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3132
    LANGUAGE sql STABLE
3133
    AS $_$
3134
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3135
$_$;
3136

    
3137

    
3138
--
3139
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3140
--
3141

    
3142
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3143
    LANGUAGE sql IMMUTABLE
3144
    AS $_$
3145
SELECT '^'||util.regexp_quote($1)||'$'
3146
$_$;
3147

    
3148

    
3149
--
3150
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3151
--
3152

    
3153
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3154
    LANGUAGE plpgsql STABLE STRICT
3155
    AS $_$
3156
DECLARE
3157
    hstore hstore;
3158
BEGIN
3159
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3160
        table_||$$))$$ INTO STRICT hstore;
3161
    RETURN hstore;
3162
END;
3163
$_$;
3164

    
3165

    
3166
--
3167
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3168
--
3169

    
3170
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3171
    LANGUAGE sql STABLE
3172
    AS $_$
3173
SELECT COUNT(*) > 0 FROM pg_constraint
3174
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3175
$_$;
3176

    
3177

    
3178
--
3179
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3180
--
3181

    
3182
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3183
gets whether a status flag is set by the presence of a table constraint
3184
';
3185

    
3186

    
3187
--
3188
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3189
--
3190

    
3191
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3192
    LANGUAGE sql
3193
    AS $_$
3194
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3195
||quote_ident($2)||$$ CHECK (true)$$)
3196
$_$;
3197

    
3198

    
3199
--
3200
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3201
--
3202

    
3203
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3204
stores a status flag by the presence of a table constraint.
3205
idempotent.
3206
';
3207

    
3208

    
3209
--
3210
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3211
--
3212

    
3213
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3214
    LANGUAGE sql STABLE
3215
    AS $_$
3216
SELECT util.table_flag__get($1, 'nulls_mapped')
3217
$_$;
3218

    
3219

    
3220
--
3221
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3222
--
3223

    
3224
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3225
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3226
';
3227

    
3228

    
3229
--
3230
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3231
--
3232

    
3233
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3234
    LANGUAGE sql
3235
    AS $_$
3236
SELECT util.table_flag__set($1, 'nulls_mapped')
3237
$_$;
3238

    
3239

    
3240
--
3241
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3242
--
3243

    
3244
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3245
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3246
idempotent.
3247
';
3248

    
3249

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

    
3254
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3255
    LANGUAGE plpgsql STRICT
3256
    AS $_$
3257
DECLARE
3258
    row record;
3259
BEGIN
3260
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3261
    LOOP
3262
        IF row.global_name != row.name THEN
3263
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3264
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3265
        END IF;
3266
    END LOOP;
3267
END;
3268
$_$;
3269

    
3270

    
3271
--
3272
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3273
--
3274

    
3275
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3276
idempotent
3277
';
3278

    
3279

    
3280
--
3281
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3282
--
3283

    
3284
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3285
    LANGUAGE sql
3286
    AS $_$
3287
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3288
SELECT NULL::void; -- don't fold away functions called in previous query
3289
$_$;
3290

    
3291

    
3292
--
3293
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3294
--
3295

    
3296
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3297
trims table_ to include only columns in the original data.
3298
idempotent.
3299
';
3300

    
3301

    
3302
--
3303
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3304
--
3305

    
3306
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3307
    LANGUAGE plpgsql STRICT
3308
    AS $_$
3309
BEGIN
3310
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3311
END;
3312
$_$;
3313

    
3314

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

    
3319
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3320
idempotent
3321
';
3322

    
3323

    
3324
--
3325
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3326
--
3327

    
3328
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3329
    LANGUAGE sql IMMUTABLE
3330
    AS $_$
3331
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3332
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3333
$_$;
3334

    
3335

    
3336
--
3337
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3338
--
3339

    
3340
CREATE FUNCTION try_create(sql text) RETURNS void
3341
    LANGUAGE plpgsql STRICT
3342
    AS $$
3343
BEGIN
3344
    PERFORM util.eval(sql);
3345
EXCEPTION
3346
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3347
    WHEN undefined_column THEN NULL;
3348
    WHEN duplicate_column THEN NULL;
3349
END;
3350
$$;
3351

    
3352

    
3353
--
3354
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3355
--
3356

    
3357
COMMENT ON FUNCTION try_create(sql text) IS '
3358
idempotent
3359
';
3360

    
3361

    
3362
--
3363
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3364
--
3365

    
3366
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3367
    LANGUAGE sql
3368
    AS $_$
3369
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3370
$_$;
3371

    
3372

    
3373
--
3374
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3375
--
3376

    
3377
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3378
idempotent
3379
';
3380

    
3381

    
3382
--
3383
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3384
--
3385

    
3386
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3387
    LANGUAGE sql IMMUTABLE
3388
    AS $_$
3389
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3390
$_$;
3391

    
3392

    
3393
--
3394
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3395
--
3396

    
3397
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3398
a type''s NOT NULL qualifier
3399
';
3400

    
3401

    
3402
--
3403
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3404
--
3405

    
3406
CREATE FUNCTION typeof(value anyelement) RETURNS text
3407
    LANGUAGE sql IMMUTABLE
3408
    AS $_$
3409
SELECT util.qual_name(pg_typeof($1))
3410
$_$;
3411

    
3412

    
3413
--
3414
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3415
--
3416

    
3417
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3418
    LANGUAGE plpgsql STABLE
3419
    AS $_$
3420
DECLARE
3421
    type regtype;
3422
BEGIN
3423
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3424
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3425
    RETURN type;
3426
END;
3427
$_$;
3428

    
3429

    
3430
--
3431
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3432
--
3433

    
3434
CREATE AGGREGATE all_same(anyelement) (
3435
    SFUNC = all_same_transform,
3436
    STYPE = anyarray,
3437
    FINALFUNC = all_same_final
3438
);
3439

    
3440

    
3441
--
3442
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3443
--
3444

    
3445
COMMENT ON AGGREGATE all_same(anyelement) IS '
3446
includes NULLs in comparison
3447
';
3448

    
3449

    
3450
--
3451
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3452
--
3453

    
3454
CREATE AGGREGATE join_strs(text, text) (
3455
    SFUNC = join_strs_transform,
3456
    STYPE = text
3457
);
3458

    
3459

    
3460
--
3461
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3462
--
3463

    
3464
CREATE OPERATOR %== (
3465
    PROCEDURE = "%==",
3466
    LEFTARG = anyelement,
3467
    RIGHTARG = anyelement
3468
);
3469

    
3470

    
3471
--
3472
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3473
--
3474

    
3475
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3476
returns whether the map-keys of the compared values are the same
3477
(mnemonic: % is the Perl symbol for a hash map)
3478

    
3479
should be overridden for types that store both keys and values
3480

    
3481
used in a FULL JOIN to select which columns to join on
3482
';
3483

    
3484

    
3485
--
3486
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3487
--
3488

    
3489
CREATE OPERATOR -> (
3490
    PROCEDURE = map_get,
3491
    LEFTARG = regclass,
3492
    RIGHTARG = text
3493
);
3494

    
3495

    
3496
--
3497
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3498
--
3499

    
3500
CREATE OPERATOR => (
3501
    PROCEDURE = hstore,
3502
    LEFTARG = text[],
3503
    RIGHTARG = text
3504
);
3505

    
3506

    
3507
--
3508
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3509
--
3510

    
3511
COMMENT ON OPERATOR => (text[], text) IS '
3512
usage: array[''key1'', ...]::text[] => ''value''
3513
';
3514

    
3515

    
3516
--
3517
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3518
--
3519

    
3520
CREATE OPERATOR ?*>= (
3521
    PROCEDURE = is_populated_more_often_than,
3522
    LEFTARG = anyelement,
3523
    RIGHTARG = anyelement
3524
);
3525

    
3526

    
3527
--
3528
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3529
--
3530

    
3531
CREATE OPERATOR ?>= (
3532
    PROCEDURE = is_more_complete_than,
3533
    LEFTARG = anyelement,
3534
    RIGHTARG = anyelement
3535
);
3536

    
3537

    
3538
--
3539
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3540
--
3541

    
3542
CREATE OPERATOR ||% (
3543
    PROCEDURE = concat_esc,
3544
    LEFTARG = text,
3545
    RIGHTARG = text
3546
);
3547

    
3548

    
3549
--
3550
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3551
--
3552

    
3553
COMMENT ON OPERATOR ||% (text, text) IS '
3554
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3555
';
3556

    
3557

    
3558
--
3559
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3560
--
3561

    
3562
CREATE TABLE map (
3563
    "from" text NOT NULL,
3564
    "to" text,
3565
    filter text,
3566
    notes text
3567
);
3568

    
3569

    
3570
--
3571
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3572
--
3573

    
3574

    
3575

    
3576
--
3577
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3578
--
3579

    
3580

    
3581

    
3582
--
3583
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3584
--
3585

    
3586
ALTER TABLE ONLY map
3587
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3588

    
3589

    
3590
--
3591
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3592
--
3593

    
3594
ALTER TABLE ONLY map
3595
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3596

    
3597

    
3598
--
3599
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3600
--
3601

    
3602
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3603

    
3604

    
3605
--
3606
-- PostgreSQL database dump complete
3607
--
3608

    
(19-19/29)