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
$$)
993
$_$;
994

    
995

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

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

    
1011

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

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

    
1020

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

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

    
1033

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

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

    
1044

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

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

    
1080

    
1081
--
1082
-- 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: -
1083
--
1084

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

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

    
1096

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

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

    
1107

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

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

    
1116

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

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

    
1128

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

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

    
1137

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

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

    
1150

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

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

    
1162

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

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

    
1171

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

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

    
1183

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

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

    
1197

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

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

    
1208

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

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

    
1217

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

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

    
1228

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

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

    
1237

    
1238
--
1239
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1240
--
1241

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

    
1248

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

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

    
1257

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

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

    
1268

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

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

    
1279

    
1280
--
1281
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1282
--
1283

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

    
1293

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

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

    
1307

    
1308
--
1309
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1310
--
1311

    
1312
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1313
col_type_null (*required*): NULL::col_type
1314
';
1315

    
1316

    
1317
--
1318
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1319
--
1320

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

    
1330

    
1331
--
1332
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1333
--
1334

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

    
1344

    
1345
--
1346
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1347
--
1348

    
1349
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1350
ret_type_null: NULL::ret_type
1351
';
1352

    
1353

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

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

    
1370

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

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

    
1379

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

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

    
1390

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

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

    
1399

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

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

    
1410

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

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

    
1420

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

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

    
1433

    
1434
--
1435
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1436
--
1437

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

    
1444

    
1445
--
1446
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1447
--
1448

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

    
1455

    
1456
--
1457
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1458
--
1459

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

    
1467

    
1468
--
1469
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1470
--
1471

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

    
1479

    
1480
SET default_tablespace = '';
1481

    
1482
SET default_with_oids = false;
1483

    
1484
--
1485
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1486
--
1487

    
1488
CREATE TABLE explain (
1489
    line text NOT NULL
1490
);
1491

    
1492

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

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

    
1505

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

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

    
1517

    
1518
--
1519
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1520
--
1521

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

    
1528

    
1529
--
1530
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1531
--
1532

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

    
1541

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

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

    
1550

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

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

    
1575

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

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

    
1583
users: not necessary to provide this because it will be autopopulated
1584
';
1585

    
1586

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

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

    
1611

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

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

    
1620

    
1621
--
1622
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1623
--
1624

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

    
1631

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

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

    
1642

    
1643
--
1644
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1645
--
1646

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

    
1653

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

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

    
1664

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

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

    
1673

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

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

    
1684

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

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

    
1693

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

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

    
1704

    
1705
--
1706
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1707
--
1708

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

    
1715

    
1716
--
1717
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1718
--
1719

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

    
1726

    
1727
--
1728
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1729
--
1730

    
1731
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1732
    LANGUAGE sql IMMUTABLE
1733
    AS $_$
1734
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1735
$_$;
1736

    
1737

    
1738
--
1739
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1740
--
1741

    
1742
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1743
    LANGUAGE sql IMMUTABLE
1744
    AS $_$
1745
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1746
$_$;
1747

    
1748

    
1749
--
1750
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1751
--
1752

    
1753
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1754
    LANGUAGE sql STABLE
1755
    AS $_$
1756
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1757
$_$;
1758

    
1759

    
1760
--
1761
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1762
--
1763

    
1764
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1765
    LANGUAGE sql STABLE
1766
    AS $_$
1767
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1768
$_$;
1769

    
1770

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

    
1775
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1776
    LANGUAGE sql IMMUTABLE STRICT
1777
    AS $_$
1778
SELECT $1 || $3 || $2
1779
$_$;
1780

    
1781

    
1782
--
1783
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1784
--
1785

    
1786
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1787
must be declared STRICT to use the special handling of STRICT aggregating functions
1788
';
1789

    
1790

    
1791
--
1792
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1793
--
1794

    
1795
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1796
    LANGUAGE sql IMMUTABLE
1797
    AS $_$
1798
SELECT $1 -- compare on the entire value
1799
$_$;
1800

    
1801

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

    
1806
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1807
    LANGUAGE sql IMMUTABLE
1808
    AS $_$
1809
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1810
$_$;
1811

    
1812

    
1813
--
1814
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1815
--
1816

    
1817
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1818
    LANGUAGE sql IMMUTABLE
1819
    AS $_$
1820
SELECT ltrim($1, $$
1821
$$)
1822
$_$;
1823

    
1824

    
1825
--
1826
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1827
--
1828

    
1829
CREATE FUNCTION map_filter_insert() RETURNS trigger
1830
    LANGUAGE plpgsql
1831
    AS $$
1832
BEGIN
1833
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1834
	RETURN new;
1835
END;
1836
$$;
1837

    
1838

    
1839
--
1840
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1841
--
1842

    
1843
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1844
    LANGUAGE plpgsql STABLE STRICT
1845
    AS $_$
1846
DECLARE
1847
    value text;
1848
BEGIN
1849
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1850
        INTO value USING key;
1851
    RETURN value;
1852
END;
1853
$_$;
1854

    
1855

    
1856
--
1857
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1858
--
1859

    
1860
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1861
    LANGUAGE sql IMMUTABLE
1862
    AS $_$
1863
SELECT util._map(util.nulls_map($1), $2)
1864
$_$;
1865

    
1866

    
1867
--
1868
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1869
--
1870

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

    
1874
[1] inlining of function calls, which is different from constant folding
1875
[2] _map()''s profiling query
1876
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1877
and map_nulls()''s profiling query
1878
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1879
both take ~920 ms.
1880
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.
1881
';
1882

    
1883

    
1884
--
1885
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1886
--
1887

    
1888
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1889
    LANGUAGE plpgsql STABLE STRICT
1890
    AS $_$
1891
BEGIN
1892
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1893
END;
1894
$_$;
1895

    
1896

    
1897
--
1898
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1899
--
1900

    
1901
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1902
    LANGUAGE sql
1903
    AS $_$
1904
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1905
$$||util.ltrim_nl($2));
1906
-- make sure the created table has the correct estimated row count
1907
SELECT util.analyze_($1);
1908
$_$;
1909

    
1910

    
1911
--
1912
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1913
--
1914

    
1915
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1916
idempotent
1917
';
1918

    
1919

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

    
1924
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1925
    LANGUAGE sql
1926
    AS $_$
1927
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1928
$_$;
1929

    
1930

    
1931
--
1932
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1933
--
1934

    
1935
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1936
idempotent
1937
';
1938

    
1939

    
1940
--
1941
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1942
--
1943

    
1944
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1945
    LANGUAGE sql
1946
    AS $_$
1947
SELECT util.create_if_not_exists($$
1948
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1949
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1950
||quote_literal($2)||$$;
1951
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1952
constant
1953
';
1954
$$)
1955
$_$;
1956

    
1957

    
1958
--
1959
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1960
--
1961

    
1962
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1963
idempotent
1964
';
1965

    
1966

    
1967
--
1968
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1969
--
1970

    
1971
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1972
    LANGUAGE plpgsql STRICT
1973
    AS $_$
1974
DECLARE
1975
    type regtype = util.typeof(expr, col.table_::text::regtype);
1976
    col_name_sql text = quote_ident(col.name);
1977
BEGIN
1978
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1979
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1980
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1981
$$||expr||$$;
1982
$$);
1983
END;
1984
$_$;
1985

    
1986

    
1987
--
1988
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1989
--
1990

    
1991
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1992
idempotent
1993
';
1994

    
1995

    
1996
--
1997
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1998
--
1999

    
2000
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2001
    LANGUAGE sql
2002
    AS $_$
2003
SELECT util.create_if_not_exists($$
2004
CREATE TABLE $$||$1||$$
2005
(
2006
    LIKE util.map INCLUDING ALL
2007
);
2008

    
2009
CREATE TRIGGER map_filter_insert
2010
  BEFORE INSERT
2011
  ON $$||$1||$$
2012
  FOR EACH ROW
2013
  EXECUTE PROCEDURE util.map_filter_insert();
2014
$$)
2015
$_$;
2016

    
2017

    
2018
--
2019
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2020
--
2021

    
2022
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2023
    LANGUAGE sql IMMUTABLE
2024
    AS $_$
2025
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
2026
$_$;
2027

    
2028

    
2029
--
2030
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2031
--
2032

    
2033
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
2034
    LANGUAGE sql IMMUTABLE
2035
    AS $_$
2036
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
2037
$_$;
2038

    
2039

    
2040
--
2041
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2042
--
2043

    
2044
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
2045
usage:
2046
for *1* schema arg:
2047
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
2048
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2049
';
2050

    
2051

    
2052
--
2053
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
2054
--
2055

    
2056
CREATE FUNCTION mk_set_search_path(search_path text) RETURNS text
2057
    LANGUAGE sql IMMUTABLE
2058
    AS $_$
2059
/* debug_print_return_value() needed because this function is used with EXECUTE
2060
rather than util.eval() (in order to affect the calling function), so the
2061
search_path would not otherwise be printed */
2062
SELECT util.debug_print_return_value($$SET LOCAL search_path TO $$||$1)
2063
$_$;
2064

    
2065

    
2066
--
2067
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2068
--
2069

    
2070
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2071
    LANGUAGE sql
2072
    AS $_$
2073
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2074
$_$;
2075

    
2076

    
2077
--
2078
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2079
--
2080

    
2081
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2082
idempotent
2083
';
2084

    
2085

    
2086
--
2087
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2088
--
2089

    
2090
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2091
    LANGUAGE plpgsql STRICT
2092
    AS $_$
2093
DECLARE
2094
	view_qual_name text = util.qual_name(view_);
2095
BEGIN
2096
	EXECUTE $$
2097
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2098
  RETURNS SETOF $$||view_||$$ AS
2099
$BODY1$
2100
SELECT * FROM $$||view_qual_name||$$
2101
ORDER BY sort_col
2102
LIMIT $1 OFFSET $2
2103
$BODY1$
2104
  LANGUAGE sql STABLE
2105
  COST 100
2106
  ROWS 1000
2107
$$;
2108
	
2109
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2110
END;
2111
$_$;
2112

    
2113

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

    
2118
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2119
    LANGUAGE plpgsql STRICT
2120
    AS $_$
2121
DECLARE
2122
	view_qual_name text = util.qual_name(view_);
2123
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2124
BEGIN
2125
	EXECUTE $$
2126
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2127
  RETURNS integer AS
2128
$BODY1$
2129
SELECT $$||quote_ident(row_num_col)||$$
2130
FROM $$||view_qual_name||$$
2131
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2132
LIMIT 1
2133
$BODY1$
2134
  LANGUAGE sql STABLE
2135
  COST 100;
2136
$$;
2137
	
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
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2144
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2145
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2146
ORDER BY $$||quote_ident(row_num_col)||$$
2147
$BODY1$
2148
  LANGUAGE sql STABLE
2149
  COST 100
2150
  ROWS 1000
2151
$$;
2152
	
2153
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2154
END;
2155
$_$;
2156

    
2157

    
2158
--
2159
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2160
--
2161

    
2162
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2163
    LANGUAGE plpgsql STRICT
2164
    AS $_$
2165
DECLARE
2166
	view_qual_name text = util.qual_name(view_);
2167
BEGIN
2168
	EXECUTE $$
2169
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2170
  RETURNS SETOF $$||view_||$$
2171
  SET enable_sort TO 'off'
2172
  AS
2173
$BODY1$
2174
SELECT * FROM $$||view_qual_name||$$($2, $3)
2175
$BODY1$
2176
  LANGUAGE sql STABLE
2177
  COST 100
2178
  ROWS 1000
2179
;
2180
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2181
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2182
If you want to run EXPLAIN and get expanded output, use the regular subset
2183
function instead. (When a config param is set on a function, EXPLAIN produces
2184
just a function scan.)
2185
';
2186
$$;
2187
END;
2188
$_$;
2189

    
2190

    
2191
--
2192
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2193
--
2194

    
2195
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2196
creates subset function which turns off enable_sort
2197
';
2198

    
2199

    
2200
--
2201
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2202
--
2203

    
2204
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2205
    LANGUAGE sql IMMUTABLE
2206
    AS $_$
2207
SELECT util.mk_set_search_path(util.schema_esc($1))
2208
$_$;
2209

    
2210

    
2211
--
2212
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2213
--
2214

    
2215
CREATE FUNCTION name(table_ regclass) RETURNS text
2216
    LANGUAGE sql STABLE
2217
    AS $_$
2218
SELECT relname::text FROM pg_class WHERE oid = $1
2219
$_$;
2220

    
2221

    
2222
--
2223
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2224
--
2225

    
2226
CREATE FUNCTION name(type regtype) RETURNS text
2227
    LANGUAGE sql STABLE
2228
    AS $_$
2229
SELECT typname::text FROM pg_type WHERE oid = $1
2230
$_$;
2231

    
2232

    
2233
--
2234
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2235
--
2236

    
2237
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2238
    LANGUAGE sql IMMUTABLE
2239
    AS $_$
2240
SELECT octet_length($1) >= util.namedatalen() - $2
2241
$_$;
2242

    
2243

    
2244
--
2245
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2246
--
2247

    
2248
CREATE FUNCTION namedatalen() RETURNS integer
2249
    LANGUAGE sql IMMUTABLE
2250
    AS $$
2251
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2252
$$;
2253

    
2254

    
2255
--
2256
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2257
--
2258

    
2259
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2260
    LANGUAGE sql IMMUTABLE
2261
    AS $_$
2262
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2263
$_$;
2264

    
2265

    
2266
--
2267
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2268
--
2269

    
2270
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2271
    LANGUAGE sql IMMUTABLE
2272
    AS $_$
2273
SELECT $1 IS NOT NULL
2274
$_$;
2275

    
2276

    
2277
--
2278
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2279
--
2280

    
2281
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2282
    LANGUAGE sql IMMUTABLE
2283
    AS $_$
2284
SELECT util.hstore($1, NULL) || '*=>*'
2285
$_$;
2286

    
2287

    
2288
--
2289
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2290
--
2291

    
2292
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2293
for use with _map()
2294
';
2295

    
2296

    
2297
--
2298
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2299
--
2300

    
2301
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2302
    LANGUAGE sql IMMUTABLE
2303
    AS $_$
2304
SELECT $2 + COALESCE($1, 0)
2305
$_$;
2306

    
2307

    
2308
--
2309
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2310
--
2311

    
2312
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2313
    LANGUAGE sql IMMUTABLE
2314
    AS $_$
2315
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2316
$_$;
2317

    
2318

    
2319
--
2320
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2321
--
2322

    
2323
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2324
    LANGUAGE sql STABLE
2325
    SET search_path TO pg_temp
2326
    AS $_$
2327
SELECT $1::text
2328
$_$;
2329

    
2330

    
2331
--
2332
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2333
--
2334

    
2335
CREATE FUNCTION qual_name(type regtype) RETURNS text
2336
    LANGUAGE sql STABLE
2337
    SET search_path TO pg_temp
2338
    AS $_$
2339
SELECT $1::text
2340
$_$;
2341

    
2342

    
2343
--
2344
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2345
--
2346

    
2347
COMMENT ON FUNCTION qual_name(type regtype) IS '
2348
a type''s schema-qualified name
2349
';
2350

    
2351

    
2352
--
2353
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2354
--
2355

    
2356
CREATE FUNCTION qual_name(type unknown) RETURNS text
2357
    LANGUAGE sql STABLE
2358
    AS $_$
2359
SELECT util.qual_name($1::text::regtype)
2360
$_$;
2361

    
2362

    
2363
--
2364
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2365
--
2366

    
2367
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2368
    LANGUAGE sql IMMUTABLE
2369
    AS $_$
2370
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2371
$_$;
2372

    
2373

    
2374
--
2375
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2376
--
2377

    
2378
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2379
    LANGUAGE sql IMMUTABLE
2380
    AS $_$
2381
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2382
$_$;
2383

    
2384

    
2385
--
2386
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2387
--
2388

    
2389
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2390
    LANGUAGE sql IMMUTABLE
2391
    AS $_$
2392
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2393
$_$;
2394

    
2395

    
2396
--
2397
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2398
--
2399

    
2400
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2401
    LANGUAGE sql IMMUTABLE
2402
    AS $_$
2403
SELECT util.raise_notice('ERROR:  '||$1)
2404
$_$;
2405

    
2406

    
2407
--
2408
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2409
--
2410

    
2411
CREATE FUNCTION raise_notice(msg text) RETURNS void
2412
    LANGUAGE plpgsql IMMUTABLE STRICT
2413
    AS $$
2414
BEGIN
2415
	RAISE NOTICE '%', msg;
2416
END;
2417
$$;
2418

    
2419

    
2420
--
2421
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2422
--
2423

    
2424
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2425
    LANGUAGE plpgsql IMMUTABLE STRICT
2426
    AS $$
2427
BEGIN
2428
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2429
END;
2430
$$;
2431

    
2432

    
2433
--
2434
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2435
--
2436

    
2437
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2438
    LANGUAGE sql IMMUTABLE
2439
    AS $_$
2440
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2441
$_$;
2442

    
2443

    
2444
--
2445
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2446
--
2447

    
2448
CREATE FUNCTION regexp_quote(str text) RETURNS text
2449
    LANGUAGE sql IMMUTABLE
2450
    AS $_$
2451
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2452
$_$;
2453

    
2454

    
2455
--
2456
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2457
--
2458

    
2459
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2460
    LANGUAGE sql IMMUTABLE
2461
    AS $_$
2462
SELECT (CASE WHEN right($1, 1) = ')'
2463
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2464
$_$;
2465

    
2466

    
2467
--
2468
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2469
--
2470

    
2471
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2472
    LANGUAGE sql STABLE
2473
    AS $_$
2474
SELECT util.relation_type(util.relation_type_char($1))
2475
$_$;
2476

    
2477

    
2478
--
2479
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2480
--
2481

    
2482
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2483
    LANGUAGE sql IMMUTABLE
2484
    AS $_$
2485
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2486
$_$;
2487

    
2488

    
2489
--
2490
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2491
--
2492

    
2493
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2494
    LANGUAGE sql STABLE
2495
    AS $_$
2496
SELECT relkind FROM pg_class WHERE oid = $1
2497
$_$;
2498

    
2499

    
2500
--
2501
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2502
--
2503

    
2504
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2505
    LANGUAGE sql
2506
    AS $_$
2507
/* can't have in_table/out_table inherit from *each other*, because inheritance
2508
also causes the rows of the parent table to be included in the child table.
2509
instead, they need to inherit from a common, empty table. */
2510
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2511
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2512
SELECT util.inherit($2, $4);
2513
SELECT util.inherit($3, $4);
2514

    
2515
SELECT util.rematerialize_query($1, $$
2516
SELECT * FROM util.diff(
2517
  $$||util.quote_typed($2)||$$
2518
, $$||util.quote_typed($3)||$$
2519
, NULL::$$||$4||$$)
2520
$$);
2521

    
2522
/* the table unfortunately cannot be *materialized* in human-readable form,
2523
because this would create column name collisions between the two sides */
2524
SELECT util.append_comment($1, '
2525
to view this table in human-readable form (with each side''s tuple column
2526
expanded to its component fields):
2527
SELECT (left_).*, (right_).* FROM '||$1||';
2528
');
2529
$_$;
2530

    
2531

    
2532
--
2533
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2534
--
2535

    
2536
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2537
type_table (*required*): table to create as the shared base type
2538
';
2539

    
2540

    
2541
--
2542
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2543
--
2544

    
2545
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2546
    LANGUAGE sql
2547
    AS $_$
2548
SELECT util.drop_table($1);
2549
SELECT util.materialize_query($1, $2);
2550
$_$;
2551

    
2552

    
2553
--
2554
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2555
--
2556

    
2557
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2558
idempotent, but repeats action each time
2559
';
2560

    
2561

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

    
2566
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2567
    LANGUAGE sql
2568
    AS $_$
2569
SELECT util.drop_table($1);
2570
SELECT util.materialize_view($1, $2);
2571
$_$;
2572

    
2573

    
2574
--
2575
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2576
--
2577

    
2578
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2579
idempotent, but repeats action each time
2580
';
2581

    
2582

    
2583
--
2584
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2585
--
2586

    
2587
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2588
    LANGUAGE sql
2589
    AS $_$
2590
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2591
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2592
FROM util.col_names($1::text::regtype) f (name);
2593
SELECT NULL::void; -- don't fold away functions called in previous query
2594
$_$;
2595

    
2596

    
2597
--
2598
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2599
--
2600

    
2601
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2602
idempotent
2603
';
2604

    
2605

    
2606
--
2607
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2608
--
2609

    
2610
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2611
    LANGUAGE sql
2612
    AS $_$
2613
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2614
included in the debug SQL */
2615
SELECT util.rename_relation(util.qual_name($1), $2)
2616
$_$;
2617

    
2618

    
2619
--
2620
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2621
--
2622

    
2623
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2624
    LANGUAGE sql
2625
    AS $_$
2626
/* 'ALTER TABLE can be used with views too'
2627
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2628
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2629
||quote_ident($2))
2630
$_$;
2631

    
2632

    
2633
--
2634
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2635
--
2636

    
2637
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2638
idempotent
2639
';
2640

    
2641

    
2642
--
2643
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2644
--
2645

    
2646
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2647
    LANGUAGE sql IMMUTABLE
2648
    AS $_$
2649
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2650
$_$;
2651

    
2652

    
2653
--
2654
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2655
--
2656

    
2657
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2658
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 
2659
';
2660

    
2661

    
2662
--
2663
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2664
--
2665

    
2666
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2667
    LANGUAGE sql
2668
    AS $_$
2669
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2670
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2671
SELECT util.set_col_names($1, $2);
2672
$_$;
2673

    
2674

    
2675
--
2676
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2677
--
2678

    
2679
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2680
idempotent.
2681
alters the names table, so it will need to be repopulated after running this function.
2682
';
2683

    
2684

    
2685
--
2686
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2687
--
2688

    
2689
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2690
    LANGUAGE sql
2691
    AS $_$
2692
SELECT util.drop_table($1);
2693
SELECT util.mk_map_table($1);
2694
$_$;
2695

    
2696

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

    
2701
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2702
    LANGUAGE sql IMMUTABLE
2703
    AS $_$
2704
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2705
$_$;
2706

    
2707

    
2708
--
2709
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2710
--
2711

    
2712
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2713
    LANGUAGE plpgsql STRICT
2714
    AS $_$
2715
DECLARE
2716
	result text = NULL;
2717
BEGIN
2718
	BEGIN
2719
		result = util.show_create_view(view_);
2720
		PERFORM util.eval($$DROP VIEW $$||view_);
2721
	EXCEPTION
2722
		WHEN undefined_table THEN NULL;
2723
	END;
2724
	RETURN result;
2725
END;
2726
$_$;
2727

    
2728

    
2729
--
2730
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2731
--
2732

    
2733
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2734
    LANGUAGE sql
2735
    AS $_$
2736
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2737
$_$;
2738

    
2739

    
2740
--
2741
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2742
--
2743

    
2744
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2745
    LANGUAGE sql STABLE
2746
    AS $_$
2747
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2748
$_$;
2749

    
2750

    
2751
--
2752
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2753
--
2754

    
2755
CREATE FUNCTION schema(table_ regclass) RETURNS text
2756
    LANGUAGE sql STABLE
2757
    AS $_$
2758
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2759
$_$;
2760

    
2761

    
2762
--
2763
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2764
--
2765

    
2766
CREATE FUNCTION schema(type regtype) RETURNS text
2767
    LANGUAGE sql STABLE
2768
    AS $_$
2769
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2770
$_$;
2771

    
2772

    
2773
--
2774
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2775
--
2776

    
2777
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2778
    LANGUAGE sql STABLE
2779
    AS $_$
2780
SELECT util.schema(pg_typeof($1))
2781
$_$;
2782

    
2783

    
2784
--
2785
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2786
--
2787

    
2788
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2789
    LANGUAGE sql STABLE
2790
    AS $_$
2791
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2792
$_$;
2793

    
2794

    
2795
--
2796
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2797
--
2798

    
2799
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2800
a schema bundle is a group of schemas with a common prefix
2801
';
2802

    
2803

    
2804
--
2805
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2806
--
2807

    
2808
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2809
    LANGUAGE sql
2810
    AS $_$
2811
SELECT util.schema_rename(old_schema,
2812
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2813
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2814
SELECT NULL::void; -- don't fold away functions called in previous query
2815
$_$;
2816

    
2817

    
2818
--
2819
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2820
--
2821

    
2822
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2823
    LANGUAGE plpgsql
2824
    AS $$
2825
BEGIN
2826
	-- don't schema_bundle_rm() the schema_bundle to keep!
2827
	IF replace = with_ THEN RETURN; END IF;
2828
	
2829
	PERFORM util.schema_bundle_rm(replace);
2830
	PERFORM util.schema_bundle_rename(with_, replace);
2831
END;
2832
$$;
2833

    
2834

    
2835
--
2836
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2837
--
2838

    
2839
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2840
    LANGUAGE sql
2841
    AS $_$
2842
SELECT util.schema_rm(schema)
2843
FROM util.schema_bundle_get_schemas($1) f (schema);
2844
SELECT NULL::void; -- don't fold away functions called in previous query
2845
$_$;
2846

    
2847

    
2848
--
2849
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2850
--
2851

    
2852
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2853
    LANGUAGE sql STABLE
2854
    AS $_$
2855
SELECT quote_ident(util.schema($1))
2856
$_$;
2857

    
2858

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

    
2863
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2864
    LANGUAGE sql IMMUTABLE
2865
    AS $_$
2866
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2867
$_$;
2868

    
2869

    
2870
--
2871
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2872
--
2873

    
2874
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2875
    LANGUAGE sql STABLE
2876
    AS $_$
2877
SELECT oid FROM pg_namespace WHERE nspname = $1
2878
$_$;
2879

    
2880

    
2881
--
2882
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2883
--
2884

    
2885
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2886
    LANGUAGE sql
2887
    AS $_$
2888
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2889
$_$;
2890

    
2891

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

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

    
2908

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

    
2913
CREATE FUNCTION schema_rm(schema text) RETURNS void
2914
    LANGUAGE sql
2915
    AS $_$
2916
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2917
$_$;
2918

    
2919

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

    
2924
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2925
    LANGUAGE sql
2926
    AS $_$
2927
SELECT util.eval(
2928
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2929
$_$;
2930

    
2931

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

    
2936
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2937
    LANGUAGE plpgsql STRICT
2938
    AS $_$
2939
DECLARE
2940
    old text[] = ARRAY(SELECT util.col_names(table_));
2941
    new text[] = ARRAY(SELECT util.map_values(names));
2942
BEGIN
2943
    old = old[1:array_length(new, 1)]; -- truncate to same length
2944
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2945
||$$ TO $$||quote_ident(value))
2946
    FROM each(hstore(old, new))
2947
    WHERE value != key -- not same name
2948
    ;
2949
END;
2950
$_$;
2951

    
2952

    
2953
--
2954
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2955
--
2956

    
2957
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2958
idempotent
2959
';
2960

    
2961

    
2962
--
2963
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2964
--
2965

    
2966
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2967
    LANGUAGE plpgsql STRICT
2968
    AS $_$
2969
DECLARE
2970
	row_ util.map;
2971
BEGIN
2972
	-- rename any metadata cols rather than re-adding them with new names
2973
	BEGIN
2974
		PERFORM util.set_col_names(table_, names);
2975
	EXCEPTION
2976
		WHEN array_subscript_error THEN -- selective suppress
2977
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2978
				-- metadata cols not yet added
2979
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2980
			END IF;
2981
	END;
2982
	
2983
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2984
	LOOP
2985
		PERFORM util.mk_const_col((table_, row_."to"),
2986
			substring(row_."from" from 2));
2987
	END LOOP;
2988
	
2989
	PERFORM util.set_col_names(table_, names);
2990
END;
2991
$_$;
2992

    
2993

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

    
2998
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2999
idempotent.
3000
the metadata mappings must be *last* in the names table.
3001
';
3002

    
3003

    
3004
--
3005
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3006
--
3007

    
3008
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3009
    LANGUAGE plpgsql STRICT
3010
    AS $_$
3011
DECLARE
3012
    sql text = $$ALTER TABLE $$||table_||$$
3013
$$||NULLIF(array_to_string(ARRAY(
3014
    SELECT
3015
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3016
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3017
    FROM
3018
    (
3019
        SELECT
3020
          quote_ident(col_name) AS col_name_sql
3021
        , util.col_type((table_, col_name)) AS curr_type
3022
        , type AS target_type
3023
        FROM unnest(col_casts)
3024
    ) s
3025
    WHERE curr_type != target_type
3026
), '
3027
, '), '');
3028
BEGIN
3029
    PERFORM util.debug_print_sql(sql);
3030
    EXECUTE COALESCE(sql, '');
3031
END;
3032
$_$;
3033

    
3034

    
3035
--
3036
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3037
--
3038

    
3039
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3040
idempotent
3041
';
3042

    
3043

    
3044
--
3045
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3046
--
3047

    
3048
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3049
    LANGUAGE sql
3050
    AS $_$
3051
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3052
$_$;
3053

    
3054

    
3055
--
3056
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3057
--
3058

    
3059
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3060
    LANGUAGE sql STABLE
3061
    AS $_$
3062
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3063
$$||util.show_grants_for($1)
3064
$_$;
3065

    
3066

    
3067
--
3068
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3069
--
3070

    
3071
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3072
    LANGUAGE sql STABLE
3073
    AS $_$
3074
SELECT string_agg(cmd, '')
3075
FROM
3076
(
3077
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3078
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3079
$$ ELSE '' END) AS cmd
3080
	FROM util.grants_users() f (user_)
3081
) s
3082
$_$;
3083

    
3084

    
3085
--
3086
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3087
--
3088

    
3089
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3090
    LANGUAGE sql STABLE
3091
    AS $_$
3092
SELECT oid FROM pg_class
3093
WHERE relkind = ANY($3) AND relname ~ $1
3094
AND util.schema_matches(util.schema(relnamespace), $2)
3095
ORDER BY relname
3096
$_$;
3097

    
3098

    
3099
--
3100
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3101
--
3102

    
3103
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3104
    LANGUAGE sql STABLE
3105
    AS $_$
3106
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3107
$_$;
3108

    
3109

    
3110
--
3111
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3112
--
3113

    
3114
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3115
    LANGUAGE sql IMMUTABLE
3116
    AS $_$
3117
SELECT '^'||util.regexp_quote($1)||'$'
3118
$_$;
3119

    
3120

    
3121
--
3122
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3123
--
3124

    
3125
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3126
    LANGUAGE plpgsql STABLE STRICT
3127
    AS $_$
3128
DECLARE
3129
    hstore hstore;
3130
BEGIN
3131
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3132
        table_||$$))$$ INTO STRICT hstore;
3133
    RETURN hstore;
3134
END;
3135
$_$;
3136

    
3137

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

    
3142
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3143
    LANGUAGE sql STABLE
3144
    AS $_$
3145
SELECT COUNT(*) > 0 FROM pg_constraint
3146
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3147
$_$;
3148

    
3149

    
3150
--
3151
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3152
--
3153

    
3154
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3155
gets whether a status flag is set by the presence of a table constraint
3156
';
3157

    
3158

    
3159
--
3160
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3161
--
3162

    
3163
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3164
    LANGUAGE sql
3165
    AS $_$
3166
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3167
||quote_ident($2)||$$ CHECK (true)$$)
3168
$_$;
3169

    
3170

    
3171
--
3172
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3173
--
3174

    
3175
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3176
stores a status flag by the presence of a table constraint.
3177
idempotent.
3178
';
3179

    
3180

    
3181
--
3182
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3183
--
3184

    
3185
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3186
    LANGUAGE sql STABLE
3187
    AS $_$
3188
SELECT util.table_flag__get($1, 'nulls_mapped')
3189
$_$;
3190

    
3191

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

    
3196
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3197
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3198
';
3199

    
3200

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

    
3205
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3206
    LANGUAGE sql
3207
    AS $_$
3208
SELECT util.table_flag__set($1, 'nulls_mapped')
3209
$_$;
3210

    
3211

    
3212
--
3213
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3214
--
3215

    
3216
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3217
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3218
idempotent.
3219
';
3220

    
3221

    
3222
--
3223
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3224
--
3225

    
3226
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3227
    LANGUAGE plpgsql STRICT
3228
    AS $_$
3229
DECLARE
3230
    row record;
3231
BEGIN
3232
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3233
    LOOP
3234
        IF row.global_name != row.name THEN
3235
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3236
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3237
        END IF;
3238
    END LOOP;
3239
END;
3240
$_$;
3241

    
3242

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

    
3247
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3248
idempotent
3249
';
3250

    
3251

    
3252
--
3253
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3254
--
3255

    
3256
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3257
    LANGUAGE sql
3258
    AS $_$
3259
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3260
SELECT NULL::void; -- don't fold away functions called in previous query
3261
$_$;
3262

    
3263

    
3264
--
3265
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3266
--
3267

    
3268
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3269
trims table_ to include only columns in the original data.
3270
idempotent.
3271
';
3272

    
3273

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

    
3278
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3279
    LANGUAGE plpgsql STRICT
3280
    AS $_$
3281
BEGIN
3282
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3283
END;
3284
$_$;
3285

    
3286

    
3287
--
3288
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3289
--
3290

    
3291
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3292
idempotent
3293
';
3294

    
3295

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

    
3300
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3301
    LANGUAGE sql IMMUTABLE
3302
    AS $_$
3303
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3304
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3305
$_$;
3306

    
3307

    
3308
--
3309
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3310
--
3311

    
3312
CREATE FUNCTION try_create(sql text) RETURNS void
3313
    LANGUAGE plpgsql STRICT
3314
    AS $$
3315
BEGIN
3316
    PERFORM util.eval(sql);
3317
EXCEPTION
3318
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3319
    WHEN undefined_column THEN NULL;
3320
    WHEN duplicate_column THEN NULL;
3321
END;
3322
$$;
3323

    
3324

    
3325
--
3326
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3327
--
3328

    
3329
COMMENT ON FUNCTION try_create(sql text) IS '
3330
idempotent
3331
';
3332

    
3333

    
3334
--
3335
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3336
--
3337

    
3338
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3339
    LANGUAGE sql
3340
    AS $_$
3341
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3342
$_$;
3343

    
3344

    
3345
--
3346
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3347
--
3348

    
3349
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3350
idempotent
3351
';
3352

    
3353

    
3354
--
3355
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3356
--
3357

    
3358
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3359
    LANGUAGE sql IMMUTABLE
3360
    AS $_$
3361
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3362
$_$;
3363

    
3364

    
3365
--
3366
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3367
--
3368

    
3369
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3370
a type''s NOT NULL qualifier
3371
';
3372

    
3373

    
3374
--
3375
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3376
--
3377

    
3378
CREATE FUNCTION typeof(value anyelement) RETURNS text
3379
    LANGUAGE sql IMMUTABLE
3380
    AS $_$
3381
SELECT util.qual_name(pg_typeof($1))
3382
$_$;
3383

    
3384

    
3385
--
3386
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3387
--
3388

    
3389
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3390
    LANGUAGE plpgsql STABLE
3391
    AS $_$
3392
DECLARE
3393
    type regtype;
3394
BEGIN
3395
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3396
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3397
    RETURN type;
3398
END;
3399
$_$;
3400

    
3401

    
3402
--
3403
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3404
--
3405

    
3406
CREATE AGGREGATE all_same(anyelement) (
3407
    SFUNC = all_same_transform,
3408
    STYPE = anyarray,
3409
    FINALFUNC = all_same_final
3410
);
3411

    
3412

    
3413
--
3414
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3415
--
3416

    
3417
COMMENT ON AGGREGATE all_same(anyelement) IS '
3418
includes NULLs in comparison
3419
';
3420

    
3421

    
3422
--
3423
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3424
--
3425

    
3426
CREATE AGGREGATE join_strs(text, text) (
3427
    SFUNC = join_strs_transform,
3428
    STYPE = text
3429
);
3430

    
3431

    
3432
--
3433
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3434
--
3435

    
3436
CREATE OPERATOR %== (
3437
    PROCEDURE = "%==",
3438
    LEFTARG = anyelement,
3439
    RIGHTARG = anyelement
3440
);
3441

    
3442

    
3443
--
3444
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3445
--
3446

    
3447
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3448
returns whether the map-keys of the compared values are the same
3449
(mnemonic: % is the Perl symbol for a hash map)
3450

    
3451
should be overridden for types that store both keys and values
3452

    
3453
used in a FULL JOIN to select which columns to join on
3454
';
3455

    
3456

    
3457
--
3458
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3459
--
3460

    
3461
CREATE OPERATOR -> (
3462
    PROCEDURE = map_get,
3463
    LEFTARG = regclass,
3464
    RIGHTARG = text
3465
);
3466

    
3467

    
3468
--
3469
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3470
--
3471

    
3472
CREATE OPERATOR => (
3473
    PROCEDURE = hstore,
3474
    LEFTARG = text[],
3475
    RIGHTARG = text
3476
);
3477

    
3478

    
3479
--
3480
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3481
--
3482

    
3483
COMMENT ON OPERATOR => (text[], text) IS '
3484
usage: array[''key1'', ...]::text[] => ''value''
3485
';
3486

    
3487

    
3488
--
3489
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3490
--
3491

    
3492
CREATE OPERATOR ?*>= (
3493
    PROCEDURE = is_populated_more_often_than,
3494
    LEFTARG = anyelement,
3495
    RIGHTARG = anyelement
3496
);
3497

    
3498

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

    
3503
CREATE OPERATOR ?>= (
3504
    PROCEDURE = is_more_complete_than,
3505
    LEFTARG = anyelement,
3506
    RIGHTARG = anyelement
3507
);
3508

    
3509

    
3510
--
3511
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3512
--
3513

    
3514
CREATE OPERATOR ||% (
3515
    PROCEDURE = concat_esc,
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
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3527
';
3528

    
3529

    
3530
--
3531
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3532
--
3533

    
3534
CREATE TABLE map (
3535
    "from" text NOT NULL,
3536
    "to" text,
3537
    filter text,
3538
    notes text
3539
);
3540

    
3541

    
3542
--
3543
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3544
--
3545

    
3546

    
3547

    
3548
--
3549
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3550
--
3551

    
3552

    
3553

    
3554
--
3555
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3556
--
3557

    
3558
ALTER TABLE ONLY map
3559
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3560

    
3561

    
3562
--
3563
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3564
--
3565

    
3566
ALTER TABLE ONLY map
3567
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3568

    
3569

    
3570
--
3571
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3572
--
3573

    
3574
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3575

    
3576

    
3577
--
3578
-- PostgreSQL database dump complete
3579
--
3580

    
(19-19/29)