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
	-- refer to EXPLAIN output for expansion of %==
1076
$$)||
1077
$$WHERE left_::$$||util.typeof($3)||$$ IS DISTINCT FROM right_::$$||util.typeof($3)||$$
1078
ORDER BY left_, right_
1079
$$, $3)
1080
	;
1081
END;
1082
$_$;
1083

    
1084

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

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

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

    
1100

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

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

    
1111

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

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

    
1120

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

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

    
1132

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

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

    
1141

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

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

    
1154

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

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

    
1166

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

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

    
1175

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

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

    
1187

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

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

    
1201

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

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

    
1212

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

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

    
1221

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

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

    
1232

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

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

    
1241

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

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

    
1252

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

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

    
1261

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

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

    
1272

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

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

    
1283

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

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

    
1297

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

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

    
1311

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

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

    
1320

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

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

    
1334

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

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

    
1348

    
1349
--
1350
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1351
--
1352

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

    
1365

    
1366
--
1367
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1368
--
1369

    
1370
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1371
ret_type_null: NULL::ret_type
1372
';
1373

    
1374

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

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

    
1385

    
1386
--
1387
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1388
--
1389

    
1390
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1391
ret_type_null: NULL::ret_type
1392
';
1393

    
1394

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

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

    
1405

    
1406
--
1407
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1408
--
1409

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

    
1415

    
1416
--
1417
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1418
--
1419

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

    
1428

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

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

    
1439

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

    
1444
CREATE FUNCTION explain2notice(sql text) RETURNS void
1445
    LANGUAGE sql
1446
    AS $_$
1447
SELECT util.raise_notice(util.explain2notice_msg($1))
1448
$_$;
1449

    
1450

    
1451
--
1452
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1453
--
1454

    
1455
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1456
    LANGUAGE sql
1457
    AS $_$
1458
SELECT $$EXPLAIN:
1459
$$||util.explain2str($1)
1460
$_$;
1461

    
1462

    
1463
--
1464
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1465
--
1466

    
1467
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1468
    LANGUAGE sql
1469
    AS $_$
1470
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1471
$_$;
1472

    
1473

    
1474
--
1475
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1476
--
1477

    
1478
CREATE FUNCTION explain2str(sql text) RETURNS text
1479
    LANGUAGE sql
1480
    AS $_$
1481
SELECT util.join_strs(explain, $$
1482
$$) FROM util.explain($1)
1483
$_$;
1484

    
1485

    
1486
SET default_tablespace = '';
1487

    
1488
SET default_with_oids = false;
1489

    
1490
--
1491
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1492
--
1493

    
1494
CREATE TABLE explain (
1495
    line text NOT NULL
1496
);
1497

    
1498

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

    
1503
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1504
    LANGUAGE sql
1505
    AS $_$
1506
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1507
$$||quote_nullable($1)||$$
1508
)$$)
1509
$_$;
1510

    
1511

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

    
1516
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1517
usage:
1518
PERFORM util.explain2table($$
1519
query
1520
$$);
1521
';
1522

    
1523

    
1524
--
1525
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1526
--
1527

    
1528
CREATE FUNCTION first_word(str text) RETURNS text
1529
    LANGUAGE sql IMMUTABLE
1530
    AS $_$
1531
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1532
$_$;
1533

    
1534

    
1535
--
1536
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1537
--
1538

    
1539
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1540
    LANGUAGE sql IMMUTABLE
1541
    AS $_$
1542
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1543
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1544
) END
1545
$_$;
1546

    
1547

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

    
1552
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1553
ensures that an array will always have proper non-NULL dimensions
1554
';
1555

    
1556

    
1557
--
1558
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1559
--
1560

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

    
1581

    
1582
--
1583
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1584
--
1585

    
1586
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1587
idempotent
1588

    
1589
users: not necessary to provide this because it will be autopopulated
1590
';
1591

    
1592

    
1593
--
1594
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1595
--
1596

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

    
1617

    
1618
--
1619
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1620
--
1621

    
1622
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1623
idempotent
1624
';
1625

    
1626

    
1627
--
1628
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1629
--
1630

    
1631
CREATE FUNCTION grants_users() RETURNS SETOF text
1632
    LANGUAGE sql IMMUTABLE
1633
    AS $$
1634
VALUES ('bien_read'), ('public_')
1635
$$;
1636

    
1637

    
1638
--
1639
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1640
--
1641

    
1642
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1643
    LANGUAGE sql IMMUTABLE
1644
    AS $_$
1645
SELECT substring($2 for length($1)) = $1
1646
$_$;
1647

    
1648

    
1649
--
1650
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1651
--
1652

    
1653
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1654
    LANGUAGE sql STABLE
1655
    AS $_$
1656
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1657
$_$;
1658

    
1659

    
1660
--
1661
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1662
--
1663

    
1664
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1665
    LANGUAGE sql IMMUTABLE
1666
    AS $_$
1667
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1668
$_$;
1669

    
1670

    
1671
--
1672
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1673
--
1674

    
1675
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1676
avoids repeating the same value for each key
1677
';
1678

    
1679

    
1680
--
1681
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1682
--
1683

    
1684
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1685
    LANGUAGE sql IMMUTABLE
1686
    AS $_$
1687
SELECT COALESCE($1, $2)
1688
$_$;
1689

    
1690

    
1691
--
1692
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1693
--
1694

    
1695
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1696
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1697
';
1698

    
1699

    
1700
--
1701
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1702
--
1703

    
1704
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1705
    LANGUAGE sql
1706
    AS $_$
1707
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1708
$_$;
1709

    
1710

    
1711
--
1712
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1713
--
1714

    
1715
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1716
    LANGUAGE sql STABLE
1717
    AS $_$
1718
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1719
$_$;
1720

    
1721

    
1722
--
1723
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1724
--
1725

    
1726
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1727
    LANGUAGE sql IMMUTABLE
1728
    AS $_$
1729
SELECT util.array_length($1) = 0
1730
$_$;
1731

    
1732

    
1733
--
1734
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1735
--
1736

    
1737
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1738
    LANGUAGE sql IMMUTABLE
1739
    AS $_$
1740
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1741
$_$;
1742

    
1743

    
1744
--
1745
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1746
--
1747

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

    
1757

    
1758
--
1759
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1760
--
1761

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

    
1768

    
1769
--
1770
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1771
--
1772

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

    
1779

    
1780
--
1781
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1782
--
1783

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

    
1790

    
1791
--
1792
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1793
--
1794

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

    
1801

    
1802
--
1803
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1804
--
1805

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

    
1812

    
1813
--
1814
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1815
--
1816

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

    
1821

    
1822
--
1823
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1824
--
1825

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

    
1832

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

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

    
1843

    
1844
--
1845
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1846
--
1847

    
1848
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1849
    LANGUAGE sql IMMUTABLE
1850
    AS $_$
1851
SELECT ltrim($1, $$
1852
$$)
1853
$_$;
1854

    
1855

    
1856
--
1857
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1858
--
1859

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

    
1869

    
1870
--
1871
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1872
--
1873

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

    
1886

    
1887
--
1888
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1889
--
1890

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

    
1897

    
1898
--
1899
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1900
--
1901

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

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

    
1914

    
1915
--
1916
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1917
--
1918

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

    
1927

    
1928
--
1929
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1930
--
1931

    
1932
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1933
    LANGUAGE sql
1934
    AS $_$
1935
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1936
$$||util.ltrim_nl($2));
1937
-- make sure the created table has the correct estimated row count
1938
SELECT util.analyze_($1);
1939
$_$;
1940

    
1941

    
1942
--
1943
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1944
--
1945

    
1946
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1947
idempotent
1948
';
1949

    
1950

    
1951
--
1952
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1953
--
1954

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

    
1961

    
1962
--
1963
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1964
--
1965

    
1966
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1967
idempotent
1968
';
1969

    
1970

    
1971
--
1972
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1973
--
1974

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

    
1988

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

    
1993
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1994
idempotent
1995
';
1996

    
1997

    
1998
--
1999
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2000
--
2001

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

    
2017

    
2018
--
2019
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2020
--
2021

    
2022
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2023
idempotent
2024
';
2025

    
2026

    
2027
--
2028
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2029
--
2030

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

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

    
2048

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

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

    
2059

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

    
2064
CREATE FUNCTION mk_set_search_path() RETURNS text
2065
    LANGUAGE sql IMMUTABLE
2066
    AS $$
2067
SELECT util.mk_set_search_path(current_setting('search_path'))
2068
$$;
2069

    
2070

    
2071
--
2072
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2073
--
2074

    
2075
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
2076
    LANGUAGE sql IMMUTABLE
2077
    AS $_$
2078
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
2079
$_$;
2080

    
2081

    
2082
--
2083
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2084
--
2085

    
2086
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
2087
usage:
2088
for *1* schema arg:
2089
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
2090
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2091
';
2092

    
2093

    
2094
--
2095
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
2096
--
2097

    
2098
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
2099
    LANGUAGE sql IMMUTABLE
2100
    AS $_$
2101
/* debug_print_return_value() needed because this function is used with EXECUTE
2102
rather than util.eval() (in order to affect the calling function), so the
2103
search_path would not otherwise be printed */
2104
SELECT util.debug_print_return_value($$SET LOCAL search_path TO $$||$1)
2105
$_$;
2106

    
2107

    
2108
--
2109
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2110
--
2111

    
2112
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2113
    LANGUAGE sql
2114
    AS $_$
2115
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2116
$_$;
2117

    
2118

    
2119
--
2120
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2121
--
2122

    
2123
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2124
idempotent
2125
';
2126

    
2127

    
2128
--
2129
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2130
--
2131

    
2132
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2133
    LANGUAGE plpgsql STRICT
2134
    AS $_$
2135
DECLARE
2136
	view_qual_name text = util.qual_name(view_);
2137
BEGIN
2138
	EXECUTE $$
2139
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2140
  RETURNS SETOF $$||view_||$$ AS
2141
$BODY1$
2142
SELECT * FROM $$||view_qual_name||$$
2143
ORDER BY sort_col
2144
LIMIT $1 OFFSET $2
2145
$BODY1$
2146
  LANGUAGE sql STABLE
2147
  COST 100
2148
  ROWS 1000
2149
$$;
2150
	
2151
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2152
END;
2153
$_$;
2154

    
2155

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

    
2160
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2161
    LANGUAGE plpgsql STRICT
2162
    AS $_$
2163
DECLARE
2164
	view_qual_name text = util.qual_name(view_);
2165
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2166
BEGIN
2167
	EXECUTE $$
2168
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2169
  RETURNS integer AS
2170
$BODY1$
2171
SELECT $$||quote_ident(row_num_col)||$$
2172
FROM $$||view_qual_name||$$
2173
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2174
LIMIT 1
2175
$BODY1$
2176
  LANGUAGE sql STABLE
2177
  COST 100;
2178
$$;
2179
	
2180
	EXECUTE $$
2181
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2182
  RETURNS SETOF $$||view_||$$ AS
2183
$BODY1$
2184
SELECT * FROM $$||view_qual_name||$$
2185
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2186
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2187
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2188
ORDER BY $$||quote_ident(row_num_col)||$$
2189
$BODY1$
2190
  LANGUAGE sql STABLE
2191
  COST 100
2192
  ROWS 1000
2193
$$;
2194
	
2195
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2196
END;
2197
$_$;
2198

    
2199

    
2200
--
2201
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2202
--
2203

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

    
2232

    
2233
--
2234
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2235
--
2236

    
2237
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2238
creates subset function which turns off enable_sort
2239
';
2240

    
2241

    
2242
--
2243
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2244
--
2245

    
2246
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2247
    LANGUAGE sql IMMUTABLE
2248
    AS $_$
2249
SELECT util.mk_set_search_path(util.schema_esc($1))
2250
$_$;
2251

    
2252

    
2253
--
2254
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2255
--
2256

    
2257
CREATE FUNCTION name(table_ regclass) RETURNS text
2258
    LANGUAGE sql STABLE
2259
    AS $_$
2260
SELECT relname::text FROM pg_class WHERE oid = $1
2261
$_$;
2262

    
2263

    
2264
--
2265
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2266
--
2267

    
2268
CREATE FUNCTION name(type regtype) RETURNS text
2269
    LANGUAGE sql STABLE
2270
    AS $_$
2271
SELECT typname::text FROM pg_type WHERE oid = $1
2272
$_$;
2273

    
2274

    
2275
--
2276
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2277
--
2278

    
2279
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2280
    LANGUAGE sql IMMUTABLE
2281
    AS $_$
2282
SELECT octet_length($1) >= util.namedatalen() - $2
2283
$_$;
2284

    
2285

    
2286
--
2287
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2288
--
2289

    
2290
CREATE FUNCTION namedatalen() RETURNS integer
2291
    LANGUAGE sql IMMUTABLE
2292
    AS $$
2293
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2294
$$;
2295

    
2296

    
2297
--
2298
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2299
--
2300

    
2301
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2302
    LANGUAGE sql IMMUTABLE
2303
    AS $_$
2304
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2305
$_$;
2306

    
2307

    
2308
--
2309
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2310
--
2311

    
2312
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2313
    LANGUAGE sql IMMUTABLE
2314
    AS $_$
2315
SELECT $1 IS NOT NULL
2316
$_$;
2317

    
2318

    
2319
--
2320
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2321
--
2322

    
2323
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2324
    LANGUAGE sql IMMUTABLE
2325
    AS $_$
2326
SELECT util.hstore($1, NULL) || '*=>*'
2327
$_$;
2328

    
2329

    
2330
--
2331
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2332
--
2333

    
2334
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2335
for use with _map()
2336
';
2337

    
2338

    
2339
--
2340
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2341
--
2342

    
2343
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2344
    LANGUAGE sql IMMUTABLE
2345
    AS $_$
2346
SELECT $2 + COALESCE($1, 0)
2347
$_$;
2348

    
2349

    
2350
--
2351
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2352
--
2353

    
2354
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2355
    LANGUAGE sql IMMUTABLE
2356
    AS $_$
2357
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2358
$_$;
2359

    
2360

    
2361
--
2362
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2363
--
2364

    
2365
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2366
    LANGUAGE sql STABLE
2367
    SET search_path TO pg_temp
2368
    AS $_$
2369
SELECT $1::text
2370
$_$;
2371

    
2372

    
2373
--
2374
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2375
--
2376

    
2377
CREATE FUNCTION qual_name(type regtype) RETURNS text
2378
    LANGUAGE sql STABLE
2379
    SET search_path TO pg_temp
2380
    AS $_$
2381
SELECT $1::text
2382
$_$;
2383

    
2384

    
2385
--
2386
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2387
--
2388

    
2389
COMMENT ON FUNCTION qual_name(type regtype) IS '
2390
a type''s schema-qualified name
2391
';
2392

    
2393

    
2394
--
2395
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2396
--
2397

    
2398
CREATE FUNCTION qual_name(type unknown) RETURNS text
2399
    LANGUAGE sql STABLE
2400
    AS $_$
2401
SELECT util.qual_name($1::text::regtype)
2402
$_$;
2403

    
2404

    
2405
--
2406
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2407
--
2408

    
2409
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2410
    LANGUAGE sql IMMUTABLE
2411
    AS $_$
2412
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2413
$_$;
2414

    
2415

    
2416
--
2417
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2418
--
2419

    
2420
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2421
    LANGUAGE sql IMMUTABLE
2422
    AS $_$
2423
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2424
$_$;
2425

    
2426

    
2427
--
2428
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2429
--
2430

    
2431
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2432
    LANGUAGE sql IMMUTABLE
2433
    AS $_$
2434
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2435
$_$;
2436

    
2437

    
2438
--
2439
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2440
--
2441

    
2442
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2443
    LANGUAGE sql IMMUTABLE
2444
    AS $_$
2445
SELECT util.raise_notice('ERROR:  '||$1)
2446
$_$;
2447

    
2448

    
2449
--
2450
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2451
--
2452

    
2453
CREATE FUNCTION raise_notice(msg text) RETURNS void
2454
    LANGUAGE plpgsql IMMUTABLE STRICT
2455
    AS $$
2456
BEGIN
2457
	RAISE NOTICE '%', msg;
2458
END;
2459
$$;
2460

    
2461

    
2462
--
2463
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2464
--
2465

    
2466
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2467
    LANGUAGE plpgsql IMMUTABLE STRICT
2468
    AS $$
2469
BEGIN
2470
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2471
END;
2472
$$;
2473

    
2474

    
2475
--
2476
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2477
--
2478

    
2479
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2480
    LANGUAGE sql IMMUTABLE
2481
    AS $_$
2482
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2483
$_$;
2484

    
2485

    
2486
--
2487
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2488
--
2489

    
2490
CREATE FUNCTION regexp_quote(str text) RETURNS text
2491
    LANGUAGE sql IMMUTABLE
2492
    AS $_$
2493
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2494
$_$;
2495

    
2496

    
2497
--
2498
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2499
--
2500

    
2501
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2502
    LANGUAGE sql IMMUTABLE
2503
    AS $_$
2504
SELECT (CASE WHEN right($1, 1) = ')'
2505
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2506
$_$;
2507

    
2508

    
2509
--
2510
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2511
--
2512

    
2513
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2514
    LANGUAGE sql STABLE
2515
    AS $_$
2516
SELECT util.relation_type(util.relation_type_char($1))
2517
$_$;
2518

    
2519

    
2520
--
2521
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2522
--
2523

    
2524
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2525
    LANGUAGE sql IMMUTABLE
2526
    AS $_$
2527
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2528
$_$;
2529

    
2530

    
2531
--
2532
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2533
--
2534

    
2535
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2536
    LANGUAGE sql STABLE
2537
    AS $_$
2538
SELECT relkind FROM pg_class WHERE oid = $1
2539
$_$;
2540

    
2541

    
2542
--
2543
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2544
--
2545

    
2546
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2547
    LANGUAGE sql
2548
    AS $_$
2549
/* can't have in_table/out_table inherit from *each other*, because inheritance
2550
also causes the rows of the parent table to be included in the child table.
2551
instead, they need to inherit from a common, empty table. */
2552
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2553
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2554
SELECT util.inherit($2, $4);
2555
SELECT util.inherit($3, $4);
2556

    
2557
SELECT util.rematerialize_query($1, $$
2558
SELECT * FROM util.diff(
2559
  $$||util.quote_typed($2)||$$
2560
, $$||util.quote_typed($3)||$$
2561
, NULL::$$||$4||$$)
2562
$$);
2563

    
2564
/* the table unfortunately cannot be *materialized* in human-readable form,
2565
because this would create column name collisions between the two sides */
2566
SELECT util.append_comment($1, '
2567
to view this table in human-readable form (with each side''s tuple column
2568
expanded to its component fields):
2569
SELECT (left_).*, (right_).* FROM '||$1||';
2570
');
2571
$_$;
2572

    
2573

    
2574
--
2575
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2576
--
2577

    
2578
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2579
type_table (*required*): table to create as the shared base type
2580
';
2581

    
2582

    
2583
--
2584
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2585
--
2586

    
2587
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2588
    LANGUAGE sql
2589
    AS $_$
2590
SELECT util.drop_table($1);
2591
SELECT util.materialize_query($1, $2);
2592
$_$;
2593

    
2594

    
2595
--
2596
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2597
--
2598

    
2599
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2600
idempotent, but repeats action each time
2601
';
2602

    
2603

    
2604
--
2605
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2606
--
2607

    
2608
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2609
    LANGUAGE sql
2610
    AS $_$
2611
SELECT util.drop_table($1);
2612
SELECT util.materialize_view($1, $2);
2613
$_$;
2614

    
2615

    
2616
--
2617
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2618
--
2619

    
2620
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2621
idempotent, but repeats action each time
2622
';
2623

    
2624

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

    
2629
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2630
    LANGUAGE sql
2631
    AS $_$
2632
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2633
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2634
FROM util.col_names($1::text::regtype) f (name);
2635
SELECT NULL::void; -- don't fold away functions called in previous query
2636
$_$;
2637

    
2638

    
2639
--
2640
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2641
--
2642

    
2643
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2644
idempotent
2645
';
2646

    
2647

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

    
2652
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2653
    LANGUAGE sql
2654
    AS $_$
2655
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2656
included in the debug SQL */
2657
SELECT util.rename_relation(util.qual_name($1), $2)
2658
$_$;
2659

    
2660

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

    
2665
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2666
    LANGUAGE sql
2667
    AS $_$
2668
/* 'ALTER TABLE can be used with views too'
2669
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2670
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2671
||quote_ident($2))
2672
$_$;
2673

    
2674

    
2675
--
2676
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2677
--
2678

    
2679
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2680
idempotent
2681
';
2682

    
2683

    
2684
--
2685
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2686
--
2687

    
2688
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2689
    LANGUAGE sql IMMUTABLE
2690
    AS $_$
2691
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2692
$_$;
2693

    
2694

    
2695
--
2696
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2697
--
2698

    
2699
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2700
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 
2701
';
2702

    
2703

    
2704
--
2705
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2706
--
2707

    
2708
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2709
    LANGUAGE sql
2710
    AS $_$
2711
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2712
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2713
SELECT util.set_col_names($1, $2);
2714
$_$;
2715

    
2716

    
2717
--
2718
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2719
--
2720

    
2721
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2722
idempotent.
2723
alters the names table, so it will need to be repopulated after running this function.
2724
';
2725

    
2726

    
2727
--
2728
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2729
--
2730

    
2731
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2732
    LANGUAGE sql
2733
    AS $_$
2734
SELECT util.drop_table($1);
2735
SELECT util.mk_map_table($1);
2736
$_$;
2737

    
2738

    
2739
--
2740
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2741
--
2742

    
2743
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2744
    LANGUAGE sql IMMUTABLE
2745
    AS $_$
2746
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2747
$_$;
2748

    
2749

    
2750
--
2751
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2752
--
2753

    
2754
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2755
    LANGUAGE plpgsql STRICT
2756
    AS $_$
2757
DECLARE
2758
	result text = NULL;
2759
BEGIN
2760
	BEGIN
2761
		result = util.show_create_view(view_);
2762
		PERFORM util.eval($$DROP VIEW $$||view_);
2763
	EXCEPTION
2764
		WHEN undefined_table THEN NULL;
2765
	END;
2766
	RETURN result;
2767
END;
2768
$_$;
2769

    
2770

    
2771
--
2772
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2773
--
2774

    
2775
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2776
    LANGUAGE sql
2777
    AS $_$
2778
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2779
$_$;
2780

    
2781

    
2782
--
2783
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2784
--
2785

    
2786
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2787
    LANGUAGE sql STABLE
2788
    AS $_$
2789
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2790
$_$;
2791

    
2792

    
2793
--
2794
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2795
--
2796

    
2797
CREATE FUNCTION schema(table_ regclass) RETURNS text
2798
    LANGUAGE sql STABLE
2799
    AS $_$
2800
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2801
$_$;
2802

    
2803

    
2804
--
2805
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2806
--
2807

    
2808
CREATE FUNCTION schema(type regtype) RETURNS text
2809
    LANGUAGE sql STABLE
2810
    AS $_$
2811
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2812
$_$;
2813

    
2814

    
2815
--
2816
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2817
--
2818

    
2819
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2820
    LANGUAGE sql STABLE
2821
    AS $_$
2822
SELECT util.schema(pg_typeof($1))
2823
$_$;
2824

    
2825

    
2826
--
2827
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2828
--
2829

    
2830
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2831
    LANGUAGE sql STABLE
2832
    AS $_$
2833
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2834
$_$;
2835

    
2836

    
2837
--
2838
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2839
--
2840

    
2841
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2842
a schema bundle is a group of schemas with a common prefix
2843
';
2844

    
2845

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

    
2850
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2851
    LANGUAGE sql
2852
    AS $_$
2853
SELECT util.schema_rename(old_schema,
2854
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2855
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2856
SELECT NULL::void; -- don't fold away functions called in previous query
2857
$_$;
2858

    
2859

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

    
2864
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2865
    LANGUAGE plpgsql
2866
    AS $$
2867
BEGIN
2868
	-- don't schema_bundle_rm() the schema_bundle to keep!
2869
	IF replace = with_ THEN RETURN; END IF;
2870
	
2871
	PERFORM util.schema_bundle_rm(replace);
2872
	PERFORM util.schema_bundle_rename(with_, replace);
2873
END;
2874
$$;
2875

    
2876

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

    
2881
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2882
    LANGUAGE sql
2883
    AS $_$
2884
SELECT util.schema_rm(schema)
2885
FROM util.schema_bundle_get_schemas($1) f (schema);
2886
SELECT NULL::void; -- don't fold away functions called in previous query
2887
$_$;
2888

    
2889

    
2890
--
2891
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2892
--
2893

    
2894
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2895
    LANGUAGE sql STABLE
2896
    AS $_$
2897
SELECT quote_ident(util.schema($1))
2898
$_$;
2899

    
2900

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

    
2905
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2906
    LANGUAGE sql IMMUTABLE
2907
    AS $_$
2908
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2909
$_$;
2910

    
2911

    
2912
--
2913
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2914
--
2915

    
2916
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2917
    LANGUAGE sql STABLE
2918
    AS $_$
2919
SELECT oid FROM pg_namespace WHERE nspname = $1
2920
$_$;
2921

    
2922

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

    
2927
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2928
    LANGUAGE sql
2929
    AS $_$
2930
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2931
$_$;
2932

    
2933

    
2934
--
2935
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2936
--
2937

    
2938
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2939
    LANGUAGE plpgsql
2940
    AS $$
2941
BEGIN
2942
	-- don't schema_rm() the schema to keep!
2943
	IF replace = with_ THEN RETURN; END IF;
2944
	
2945
	PERFORM util.schema_rm(replace);
2946
	PERFORM util.schema_rename(with_, replace);
2947
END;
2948
$$;
2949

    
2950

    
2951
--
2952
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2953
--
2954

    
2955
CREATE FUNCTION schema_rm(schema text) RETURNS void
2956
    LANGUAGE sql
2957
    AS $_$
2958
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2959
$_$;
2960

    
2961

    
2962
--
2963
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2964
--
2965

    
2966
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2967
    LANGUAGE sql
2968
    AS $_$
2969
SELECT util.eval(
2970
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2971
$_$;
2972

    
2973

    
2974
--
2975
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2976
--
2977

    
2978
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2979
    LANGUAGE plpgsql STRICT
2980
    AS $_$
2981
DECLARE
2982
    old text[] = ARRAY(SELECT util.col_names(table_));
2983
    new text[] = ARRAY(SELECT util.map_values(names));
2984
BEGIN
2985
    old = old[1:array_length(new, 1)]; -- truncate to same length
2986
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2987
||$$ TO $$||quote_ident(value))
2988
    FROM each(hstore(old, new))
2989
    WHERE value != key -- not same name
2990
    ;
2991
END;
2992
$_$;
2993

    
2994

    
2995
--
2996
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2997
--
2998

    
2999
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3000
idempotent
3001
';
3002

    
3003

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

    
3008
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3009
    LANGUAGE plpgsql STRICT
3010
    AS $_$
3011
DECLARE
3012
	row_ util.map;
3013
BEGIN
3014
	-- rename any metadata cols rather than re-adding them with new names
3015
	BEGIN
3016
		PERFORM util.set_col_names(table_, names);
3017
	EXCEPTION
3018
		WHEN array_subscript_error THEN -- selective suppress
3019
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3020
				-- metadata cols not yet added
3021
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
3022
			END IF;
3023
	END;
3024
	
3025
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3026
	LOOP
3027
		PERFORM util.mk_const_col((table_, row_."to"),
3028
			substring(row_."from" from 2));
3029
	END LOOP;
3030
	
3031
	PERFORM util.set_col_names(table_, names);
3032
END;
3033
$_$;
3034

    
3035

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

    
3040
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3041
idempotent.
3042
the metadata mappings must be *last* in the names table.
3043
';
3044

    
3045

    
3046
--
3047
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3048
--
3049

    
3050
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3051
    LANGUAGE plpgsql STRICT
3052
    AS $_$
3053
DECLARE
3054
    sql text = $$ALTER TABLE $$||table_||$$
3055
$$||NULLIF(array_to_string(ARRAY(
3056
    SELECT
3057
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3058
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3059
    FROM
3060
    (
3061
        SELECT
3062
          quote_ident(col_name) AS col_name_sql
3063
        , util.col_type((table_, col_name)) AS curr_type
3064
        , type AS target_type
3065
        FROM unnest(col_casts)
3066
    ) s
3067
    WHERE curr_type != target_type
3068
), '
3069
, '), '');
3070
BEGIN
3071
    PERFORM util.debug_print_sql(sql);
3072
    EXECUTE COALESCE(sql, '');
3073
END;
3074
$_$;
3075

    
3076

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

    
3081
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3082
idempotent
3083
';
3084

    
3085

    
3086
--
3087
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3088
--
3089

    
3090
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3091
    LANGUAGE sql
3092
    AS $_$
3093
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3094
$_$;
3095

    
3096

    
3097
--
3098
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3099
--
3100

    
3101
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3102
    LANGUAGE sql STABLE
3103
    AS $_$
3104
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3105
$$||util.show_grants_for($1)
3106
$_$;
3107

    
3108

    
3109
--
3110
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3111
--
3112

    
3113
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3114
    LANGUAGE sql STABLE
3115
    AS $_$
3116
SELECT string_agg(cmd, '')
3117
FROM
3118
(
3119
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3120
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3121
$$ ELSE '' END) AS cmd
3122
	FROM util.grants_users() f (user_)
3123
) s
3124
$_$;
3125

    
3126

    
3127
--
3128
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3129
--
3130

    
3131
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3132
    LANGUAGE sql STABLE
3133
    AS $_$
3134
SELECT oid FROM pg_class
3135
WHERE relkind = ANY($3) AND relname ~ $1
3136
AND util.schema_matches(util.schema(relnamespace), $2)
3137
ORDER BY relname
3138
$_$;
3139

    
3140

    
3141
--
3142
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3143
--
3144

    
3145
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3146
    LANGUAGE sql STABLE
3147
    AS $_$
3148
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3149
$_$;
3150

    
3151

    
3152
--
3153
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3154
--
3155

    
3156
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3157
    LANGUAGE sql IMMUTABLE
3158
    AS $_$
3159
SELECT '^'||util.regexp_quote($1)||'$'
3160
$_$;
3161

    
3162

    
3163
--
3164
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3165
--
3166

    
3167
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3168
    LANGUAGE plpgsql STABLE STRICT
3169
    AS $_$
3170
DECLARE
3171
    hstore hstore;
3172
BEGIN
3173
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3174
        table_||$$))$$ INTO STRICT hstore;
3175
    RETURN hstore;
3176
END;
3177
$_$;
3178

    
3179

    
3180
--
3181
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3182
--
3183

    
3184
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3185
    LANGUAGE sql STABLE
3186
    AS $_$
3187
SELECT COUNT(*) > 0 FROM pg_constraint
3188
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3189
$_$;
3190

    
3191

    
3192
--
3193
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3194
--
3195

    
3196
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3197
gets whether a status flag is set by the presence of a table constraint
3198
';
3199

    
3200

    
3201
--
3202
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3203
--
3204

    
3205
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3206
    LANGUAGE sql
3207
    AS $_$
3208
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3209
||quote_ident($2)||$$ CHECK (true)$$)
3210
$_$;
3211

    
3212

    
3213
--
3214
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3215
--
3216

    
3217
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3218
stores a status flag by the presence of a table constraint.
3219
idempotent.
3220
';
3221

    
3222

    
3223
--
3224
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3225
--
3226

    
3227
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3228
    LANGUAGE sql STABLE
3229
    AS $_$
3230
SELECT util.table_flag__get($1, 'nulls_mapped')
3231
$_$;
3232

    
3233

    
3234
--
3235
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3236
--
3237

    
3238
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3239
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3240
';
3241

    
3242

    
3243
--
3244
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3245
--
3246

    
3247
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3248
    LANGUAGE sql
3249
    AS $_$
3250
SELECT util.table_flag__set($1, 'nulls_mapped')
3251
$_$;
3252

    
3253

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

    
3258
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3259
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3260
idempotent.
3261
';
3262

    
3263

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

    
3268
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3269
    LANGUAGE plpgsql STRICT
3270
    AS $_$
3271
DECLARE
3272
    row record;
3273
BEGIN
3274
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3275
    LOOP
3276
        IF row.global_name != row.name THEN
3277
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3278
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3279
        END IF;
3280
    END LOOP;
3281
END;
3282
$_$;
3283

    
3284

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

    
3289
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3290
idempotent
3291
';
3292

    
3293

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

    
3298
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3299
    LANGUAGE sql
3300
    AS $_$
3301
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3302
SELECT NULL::void; -- don't fold away functions called in previous query
3303
$_$;
3304

    
3305

    
3306
--
3307
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3308
--
3309

    
3310
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3311
trims table_ to include only columns in the original data.
3312
idempotent.
3313
';
3314

    
3315

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

    
3320
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3321
    LANGUAGE plpgsql STRICT
3322
    AS $_$
3323
BEGIN
3324
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3325
END;
3326
$_$;
3327

    
3328

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

    
3333
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3334
idempotent
3335
';
3336

    
3337

    
3338
--
3339
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3340
--
3341

    
3342
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3343
    LANGUAGE sql IMMUTABLE
3344
    AS $_$
3345
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3346
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3347
$_$;
3348

    
3349

    
3350
--
3351
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3352
--
3353

    
3354
CREATE FUNCTION try_create(sql text) RETURNS void
3355
    LANGUAGE plpgsql STRICT
3356
    AS $$
3357
BEGIN
3358
    PERFORM util.eval(sql);
3359
EXCEPTION
3360
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3361
    WHEN undefined_column THEN NULL;
3362
    WHEN duplicate_column THEN NULL;
3363
END;
3364
$$;
3365

    
3366

    
3367
--
3368
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3369
--
3370

    
3371
COMMENT ON FUNCTION try_create(sql text) IS '
3372
idempotent
3373
';
3374

    
3375

    
3376
--
3377
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3378
--
3379

    
3380
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3381
    LANGUAGE sql
3382
    AS $_$
3383
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3384
$_$;
3385

    
3386

    
3387
--
3388
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3389
--
3390

    
3391
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3392
idempotent
3393
';
3394

    
3395

    
3396
--
3397
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3398
--
3399

    
3400
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3401
    LANGUAGE sql IMMUTABLE
3402
    AS $_$
3403
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3404
$_$;
3405

    
3406

    
3407
--
3408
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3409
--
3410

    
3411
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3412
a type''s NOT NULL qualifier
3413
';
3414

    
3415

    
3416
--
3417
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3418
--
3419

    
3420
CREATE FUNCTION typeof(value anyelement) RETURNS text
3421
    LANGUAGE sql IMMUTABLE
3422
    AS $_$
3423
SELECT util.qual_name(pg_typeof($1))
3424
$_$;
3425

    
3426

    
3427
--
3428
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3429
--
3430

    
3431
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3432
    LANGUAGE plpgsql STABLE
3433
    AS $_$
3434
DECLARE
3435
    type regtype;
3436
BEGIN
3437
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3438
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3439
    RETURN type;
3440
END;
3441
$_$;
3442

    
3443

    
3444
--
3445
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3446
--
3447

    
3448
CREATE AGGREGATE all_same(anyelement) (
3449
    SFUNC = all_same_transform,
3450
    STYPE = anyarray,
3451
    FINALFUNC = all_same_final
3452
);
3453

    
3454

    
3455
--
3456
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3457
--
3458

    
3459
COMMENT ON AGGREGATE all_same(anyelement) IS '
3460
includes NULLs in comparison
3461
';
3462

    
3463

    
3464
--
3465
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3466
--
3467

    
3468
CREATE AGGREGATE join_strs(text, text) (
3469
    SFUNC = join_strs_transform,
3470
    STYPE = text
3471
);
3472

    
3473

    
3474
--
3475
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3476
--
3477

    
3478
CREATE OPERATOR %== (
3479
    PROCEDURE = "%==",
3480
    LEFTARG = anyelement,
3481
    RIGHTARG = anyelement
3482
);
3483

    
3484

    
3485
--
3486
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3487
--
3488

    
3489
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3490
returns whether the map-keys of the compared values are the same
3491
(mnemonic: % is the Perl symbol for a hash map)
3492

    
3493
should be overridden for types that store both keys and values
3494

    
3495
used in a FULL JOIN to select which columns to join on
3496
';
3497

    
3498

    
3499
--
3500
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3501
--
3502

    
3503
CREATE OPERATOR -> (
3504
    PROCEDURE = map_get,
3505
    LEFTARG = regclass,
3506
    RIGHTARG = text
3507
);
3508

    
3509

    
3510
--
3511
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3512
--
3513

    
3514
CREATE OPERATOR => (
3515
    PROCEDURE = hstore,
3516
    LEFTARG = text[],
3517
    RIGHTARG = text
3518
);
3519

    
3520

    
3521
--
3522
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3523
--
3524

    
3525
COMMENT ON OPERATOR => (text[], text) IS '
3526
usage: array[''key1'', ...]::text[] => ''value''
3527
';
3528

    
3529

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

    
3534
CREATE OPERATOR ?*>= (
3535
    PROCEDURE = is_populated_more_often_than,
3536
    LEFTARG = anyelement,
3537
    RIGHTARG = anyelement
3538
);
3539

    
3540

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

    
3545
CREATE OPERATOR ?>= (
3546
    PROCEDURE = is_more_complete_than,
3547
    LEFTARG = anyelement,
3548
    RIGHTARG = anyelement
3549
);
3550

    
3551

    
3552
--
3553
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3554
--
3555

    
3556
CREATE OPERATOR ||% (
3557
    PROCEDURE = concat_esc,
3558
    LEFTARG = text,
3559
    RIGHTARG = text
3560
);
3561

    
3562

    
3563
--
3564
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3565
--
3566

    
3567
COMMENT ON OPERATOR ||% (text, text) IS '
3568
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3569
';
3570

    
3571

    
3572
--
3573
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3574
--
3575

    
3576
CREATE TABLE map (
3577
    "from" text NOT NULL,
3578
    "to" text,
3579
    filter text,
3580
    notes text
3581
);
3582

    
3583

    
3584
--
3585
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3586
--
3587

    
3588

    
3589

    
3590
--
3591
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3592
--
3593

    
3594

    
3595

    
3596
--
3597
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3598
--
3599

    
3600
ALTER TABLE ONLY map
3601
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3602

    
3603

    
3604
--
3605
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3606
--
3607

    
3608
ALTER TABLE ONLY map
3609
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3610

    
3611

    
3612
--
3613
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3614
--
3615

    
3616
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3617

    
3618

    
3619
--
3620
-- PostgreSQL database dump complete
3621
--
3622

    
(19-19/29)