Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

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

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

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

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

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

    
84

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

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

    
93

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

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

    
104

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

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

    
124

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

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

    
133

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

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

    
153

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

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

    
172

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

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

    
190

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

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

    
201

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

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

    
212

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

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

    
225

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

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

    
236

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

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

    
247

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

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

    
258

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

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

    
269

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

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

    
280

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

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

    
291

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

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

    
306

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

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

    
331

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

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

    
342

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

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

    
381

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

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

    
392

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

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

    
431

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

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

    
442

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

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

    
453

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

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

    
464

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

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

    
475

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

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

    
501

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

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

    
521

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

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

    
530

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

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

    
541

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

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

    
552

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

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

    
570

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

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

    
579

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

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

    
590

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

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

    
607

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

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

    
618

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

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

    
629

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

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

    
638

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

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

    
649

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

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

    
660

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

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

    
671

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

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

    
680

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

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

    
691

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

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

    
707

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

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

    
716

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

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

    
732

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

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

    
756

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

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

    
779

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

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

    
790

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

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

    
799

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

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

    
815

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

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

    
832

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

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

    
846

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

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

    
859

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

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

    
882

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

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

    
893

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

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

    
904

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

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

    
915

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

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

    
926

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

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

    
947

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

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

    
956

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

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

    
967

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

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

    
980

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

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

    
995

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

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

    
1011

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

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

    
1020

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

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

    
1033

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

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

    
1044

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

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

    
1081

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

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

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

    
1097

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

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

    
1108

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

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

    
1117

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

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

    
1129

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

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

    
1138

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

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

    
1151

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

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

    
1163

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

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

    
1172

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

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

    
1184

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

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

    
1198

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

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

    
1209

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

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

    
1218

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

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

    
1229

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

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

    
1238

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

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

    
1249

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

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

    
1258

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

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

    
1269

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

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

    
1280

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

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

    
1294

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

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

    
1308

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

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

    
1317

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

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

    
1331

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

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

    
1345

    
1346
--
1347
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1348
--
1349

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

    
1362

    
1363
--
1364
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1365
--
1366

    
1367
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1368
ret_type_null: NULL::ret_type
1369
';
1370

    
1371

    
1372
--
1373
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1374
--
1375

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

    
1382

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

    
1387
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1388
ret_type_null: NULL::ret_type
1389
';
1390

    
1391

    
1392
--
1393
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1394
--
1395

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

    
1402

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

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

    
1412

    
1413
--
1414
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1415
--
1416

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

    
1425

    
1426
--
1427
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1428
--
1429

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

    
1436

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

    
1441
CREATE FUNCTION explain2notice(sql text) RETURNS void
1442
    LANGUAGE sql
1443
    AS $_$
1444
SELECT util.raise_notice(util.explain2notice_msg($1))
1445
$_$;
1446

    
1447

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

    
1452
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1453
    LANGUAGE sql
1454
    AS $_$
1455
-- newline before and after to visually separate it from other debug info
1456
SELECT $$
1457
EXPLAIN:
1458
$$||util.explain2str($1)||$$
1459
$$
1460
$_$;
1461

    
1462

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

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

    
1473

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

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

    
1485

    
1486
SET default_tablespace = '';
1487

    
1488
SET default_with_oids = false;
1489

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

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

    
1498

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

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

    
1511

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

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

    
1523

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

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

    
1534

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

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

    
1547

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

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

    
1556

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

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

    
1581

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

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

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

    
1592

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

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

    
1617

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

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

    
1626

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

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

    
1637

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

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

    
1648

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

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

    
1659

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

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

    
1670

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

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

    
1679

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

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

    
1690

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

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

    
1699

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

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

    
1710

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

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

    
1721

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

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

    
1732

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

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

    
1743

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

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

    
1757

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

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

    
1768

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

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

    
1779

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

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

    
1790

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

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

    
1801

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

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

    
1812

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

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

    
1821

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

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

    
1832

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

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

    
1843

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

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

    
1855

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

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

    
1869

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

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

    
1886

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

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

    
1897

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

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

    
1905
[1] inlining of function calls, which is different from constant folding
1906
[2] _map()''s profiling query
1907
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1908
and map_nulls()''s profiling query
1909
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1910
both take ~920 ms.
1911
also, /inputs/REMIB/Specimen/postprocess.sql > country takes the same amount of time (56000 ms) to build with map_nulls() as with a literal hstore.
1912
';
1913

    
1914

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

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

    
1927

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

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

    
1940
SELECT util.append_comment($1, '
1941
contents generated from:
1942
'||util.ltrim_nl($2)||';
1943
');
1944
$_$;
1945

    
1946

    
1947
--
1948
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1949
--
1950

    
1951
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1952
idempotent
1953
';
1954

    
1955

    
1956
--
1957
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1958
--
1959

    
1960
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1961
    LANGUAGE sql
1962
    AS $_$
1963
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1964
$_$;
1965

    
1966

    
1967
--
1968
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1969
--
1970

    
1971
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1972
idempotent
1973
';
1974

    
1975

    
1976
--
1977
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1978
--
1979

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

    
1993

    
1994
--
1995
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1996
--
1997

    
1998
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1999
idempotent
2000
';
2001

    
2002

    
2003
--
2004
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2005
--
2006

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

    
2022

    
2023
--
2024
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2025
--
2026

    
2027
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2028
idempotent
2029
';
2030

    
2031

    
2032
--
2033
-- Name: mk_diff_query(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2034
--
2035

    
2036
CREATE FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean DEFAULT false) RETURNS text
2037
    LANGUAGE sql IMMUTABLE
2038
    AS $_$
2039
SELECT
2040
$$SELECT left_, right_
2041
FROM $$||$1||$$ left_
2042
$$||util._if($3, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
2043
$$||util._if($3, ''::text,
2044
$$ON left_ %== right_ -- refer to EXPLAIN output for expansion of %==
2045
$$)||
2046
$$WHERE left_ IS DISTINCT FROM right_
2047
ORDER BY left_, right_
2048
$$
2049
$_$;
2050

    
2051

    
2052
--
2053
-- Name: FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean); Type: COMMENT; Schema: util; Owner: -
2054
--
2055

    
2056
COMMENT ON FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean) IS '
2057
single_row: whether the tables consist of a single row, which should be
2058
	displayed side-by-side
2059
';
2060

    
2061

    
2062
--
2063
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2064
--
2065

    
2066
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2067
    LANGUAGE sql
2068
    AS $_$
2069
SELECT util.create_if_not_exists($$
2070
CREATE TABLE $$||$1||$$
2071
(
2072
    LIKE util.map INCLUDING ALL
2073
);
2074

    
2075
CREATE TRIGGER map_filter_insert
2076
  BEFORE INSERT
2077
  ON $$||$1||$$
2078
  FOR EACH ROW
2079
  EXECUTE PROCEDURE util.map_filter_insert();
2080
$$)
2081
$_$;
2082

    
2083

    
2084
--
2085
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2086
--
2087

    
2088
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2089
    LANGUAGE sql IMMUTABLE
2090
    AS $_$
2091
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
2092
$_$;
2093

    
2094

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

    
2099
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
2100
    LANGUAGE sql IMMUTABLE
2101
    AS $_$
2102
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
2103
$_$;
2104

    
2105

    
2106
--
2107
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2108
--
2109

    
2110
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
2111
usage:
2112
for *1* schema arg:
2113
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
2114
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2115
';
2116

    
2117

    
2118
--
2119
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2120
--
2121

    
2122
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2123
    LANGUAGE sql IMMUTABLE
2124
    AS $_$
2125
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2126
$_$;
2127

    
2128

    
2129
--
2130
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2131
--
2132

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

    
2143

    
2144
--
2145
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2146
--
2147

    
2148
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2149
    LANGUAGE sql
2150
    AS $_$
2151
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2152
$_$;
2153

    
2154

    
2155
--
2156
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2157
--
2158

    
2159
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2160
idempotent
2161
';
2162

    
2163

    
2164
--
2165
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2166
--
2167

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

    
2191

    
2192
--
2193
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2194
--
2195

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

    
2235

    
2236
--
2237
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2238
--
2239

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

    
2268

    
2269
--
2270
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2271
--
2272

    
2273
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2274
creates subset function which turns off enable_sort
2275
';
2276

    
2277

    
2278
--
2279
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2280
--
2281

    
2282
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2283
    LANGUAGE sql IMMUTABLE
2284
    AS $_$
2285
SELECT util.mk_set_search_path(util.schema_esc($1))
2286
$_$;
2287

    
2288

    
2289
--
2290
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2291
--
2292

    
2293
CREATE FUNCTION name(table_ regclass) RETURNS text
2294
    LANGUAGE sql STABLE
2295
    AS $_$
2296
SELECT relname::text FROM pg_class WHERE oid = $1
2297
$_$;
2298

    
2299

    
2300
--
2301
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2302
--
2303

    
2304
CREATE FUNCTION name(type regtype) RETURNS text
2305
    LANGUAGE sql STABLE
2306
    AS $_$
2307
SELECT typname::text FROM pg_type WHERE oid = $1
2308
$_$;
2309

    
2310

    
2311
--
2312
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2313
--
2314

    
2315
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2316
    LANGUAGE sql IMMUTABLE
2317
    AS $_$
2318
SELECT octet_length($1) >= util.namedatalen() - $2
2319
$_$;
2320

    
2321

    
2322
--
2323
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2324
--
2325

    
2326
CREATE FUNCTION namedatalen() RETURNS integer
2327
    LANGUAGE sql IMMUTABLE
2328
    AS $$
2329
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2330
$$;
2331

    
2332

    
2333
--
2334
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2335
--
2336

    
2337
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2338
    LANGUAGE sql IMMUTABLE
2339
    AS $_$
2340
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2341
$_$;
2342

    
2343

    
2344
--
2345
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2346
--
2347

    
2348
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2349
    LANGUAGE sql IMMUTABLE
2350
    AS $_$
2351
SELECT $1 IS NOT NULL
2352
$_$;
2353

    
2354

    
2355
--
2356
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2357
--
2358

    
2359
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2360
    LANGUAGE sql IMMUTABLE
2361
    AS $_$
2362
SELECT util.hstore($1, NULL) || '*=>*'
2363
$_$;
2364

    
2365

    
2366
--
2367
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2368
--
2369

    
2370
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2371
for use with _map()
2372
';
2373

    
2374

    
2375
--
2376
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2377
--
2378

    
2379
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2380
    LANGUAGE sql IMMUTABLE
2381
    AS $_$
2382
SELECT $2 + COALESCE($1, 0)
2383
$_$;
2384

    
2385

    
2386
--
2387
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2388
--
2389

    
2390
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2391
    LANGUAGE sql IMMUTABLE
2392
    AS $_$
2393
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2394
$_$;
2395

    
2396

    
2397
--
2398
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2399
--
2400

    
2401
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2402
    LANGUAGE sql STABLE
2403
    SET search_path TO pg_temp
2404
    AS $_$
2405
SELECT $1::text
2406
$_$;
2407

    
2408

    
2409
--
2410
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2411
--
2412

    
2413
CREATE FUNCTION qual_name(type regtype) RETURNS text
2414
    LANGUAGE sql STABLE
2415
    SET search_path TO pg_temp
2416
    AS $_$
2417
SELECT $1::text
2418
$_$;
2419

    
2420

    
2421
--
2422
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2423
--
2424

    
2425
COMMENT ON FUNCTION qual_name(type regtype) IS '
2426
a type''s schema-qualified name
2427
';
2428

    
2429

    
2430
--
2431
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2432
--
2433

    
2434
CREATE FUNCTION qual_name(type unknown) RETURNS text
2435
    LANGUAGE sql STABLE
2436
    AS $_$
2437
SELECT util.qual_name($1::text::regtype)
2438
$_$;
2439

    
2440

    
2441
--
2442
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2443
--
2444

    
2445
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2446
    LANGUAGE sql IMMUTABLE
2447
    AS $_$
2448
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2449
$_$;
2450

    
2451

    
2452
--
2453
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2454
--
2455

    
2456
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2457
    LANGUAGE sql IMMUTABLE
2458
    AS $_$
2459
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2460
$_$;
2461

    
2462

    
2463
--
2464
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2465
--
2466

    
2467
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2468
    LANGUAGE sql IMMUTABLE
2469
    AS $_$
2470
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2471
$_$;
2472

    
2473

    
2474
--
2475
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2476
--
2477

    
2478
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2479
    LANGUAGE sql IMMUTABLE
2480
    AS $_$
2481
SELECT util.raise_notice('ERROR:  '||$1)
2482
$_$;
2483

    
2484

    
2485
--
2486
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2487
--
2488

    
2489
CREATE FUNCTION raise_notice(msg text) RETURNS void
2490
    LANGUAGE plpgsql IMMUTABLE STRICT
2491
    AS $$
2492
BEGIN
2493
	RAISE NOTICE '%', msg;
2494
END;
2495
$$;
2496

    
2497

    
2498
--
2499
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2500
--
2501

    
2502
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2503
    LANGUAGE plpgsql IMMUTABLE STRICT
2504
    AS $$
2505
BEGIN
2506
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2507
END;
2508
$$;
2509

    
2510

    
2511
--
2512
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2513
--
2514

    
2515
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2516
    LANGUAGE sql IMMUTABLE
2517
    AS $_$
2518
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2519
$_$;
2520

    
2521

    
2522
--
2523
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2524
--
2525

    
2526
CREATE FUNCTION regexp_quote(str text) RETURNS text
2527
    LANGUAGE sql IMMUTABLE
2528
    AS $_$
2529
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2530
$_$;
2531

    
2532

    
2533
--
2534
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2535
--
2536

    
2537
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2538
    LANGUAGE sql IMMUTABLE
2539
    AS $_$
2540
SELECT (CASE WHEN right($1, 1) = ')'
2541
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2542
$_$;
2543

    
2544

    
2545
--
2546
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2547
--
2548

    
2549
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2550
    LANGUAGE sql STABLE
2551
    AS $_$
2552
SELECT util.relation_type(util.relation_type_char($1))
2553
$_$;
2554

    
2555

    
2556
--
2557
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2558
--
2559

    
2560
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2561
    LANGUAGE sql IMMUTABLE
2562
    AS $_$
2563
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2564
$_$;
2565

    
2566

    
2567
--
2568
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2569
--
2570

    
2571
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2572
    LANGUAGE sql STABLE
2573
    AS $_$
2574
SELECT relkind FROM pg_class WHERE oid = $1
2575
$_$;
2576

    
2577

    
2578
--
2579
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2580
--
2581

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

    
2593
SELECT util.rematerialize_query($1, $$
2594
SELECT * FROM util.diff(
2595
  $$||util.quote_typed($2)||$$
2596
, $$||util.quote_typed($3)||$$
2597
, NULL::$$||$4||$$)
2598
$$);
2599

    
2600
/* the table unfortunately cannot be *materialized* in human-readable form,
2601
because this would create column name collisions between the two sides */
2602
SELECT util.append_comment($1, '
2603
to view this table in human-readable form (with each side''s tuple column
2604
expanded to its component fields):
2605
SELECT (left_).*, (right_).* FROM '||$1||';
2606
');
2607
$_$;
2608

    
2609

    
2610
--
2611
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2612
--
2613

    
2614
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2615
type_table (*required*): table to create as the shared base type
2616
';
2617

    
2618

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

    
2623
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2624
    LANGUAGE sql
2625
    AS $_$
2626
SELECT util.drop_table($1);
2627
SELECT util.materialize_query($1, $2);
2628
$_$;
2629

    
2630

    
2631
--
2632
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2633
--
2634

    
2635
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2636
idempotent, but repeats action each time
2637
';
2638

    
2639

    
2640
--
2641
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2642
--
2643

    
2644
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2645
    LANGUAGE sql
2646
    AS $_$
2647
SELECT util.drop_table($1);
2648
SELECT util.materialize_view($1, $2);
2649
$_$;
2650

    
2651

    
2652
--
2653
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2654
--
2655

    
2656
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2657
idempotent, but repeats action each time
2658
';
2659

    
2660

    
2661
--
2662
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2663
--
2664

    
2665
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2666
    LANGUAGE sql
2667
    AS $_$
2668
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2669
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2670
FROM util.col_names($1::text::regtype) f (name);
2671
SELECT NULL::void; -- don't fold away functions called in previous query
2672
$_$;
2673

    
2674

    
2675
--
2676
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2677
--
2678

    
2679
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2680
idempotent
2681
';
2682

    
2683

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

    
2688
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2689
    LANGUAGE sql
2690
    AS $_$
2691
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2692
included in the debug SQL */
2693
SELECT util.rename_relation(util.qual_name($1), $2)
2694
$_$;
2695

    
2696

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

    
2701
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2702
    LANGUAGE sql
2703
    AS $_$
2704
/* 'ALTER TABLE can be used with views too'
2705
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2706
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2707
||quote_ident($2))
2708
$_$;
2709

    
2710

    
2711
--
2712
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2713
--
2714

    
2715
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2716
idempotent
2717
';
2718

    
2719

    
2720
--
2721
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2722
--
2723

    
2724
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2725
    LANGUAGE sql IMMUTABLE
2726
    AS $_$
2727
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2728
$_$;
2729

    
2730

    
2731
--
2732
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2733
--
2734

    
2735
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2736
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 
2737
';
2738

    
2739

    
2740
--
2741
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2742
--
2743

    
2744
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2745
    LANGUAGE sql
2746
    AS $_$
2747
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2748
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2749
SELECT util.set_col_names($1, $2);
2750
$_$;
2751

    
2752

    
2753
--
2754
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2755
--
2756

    
2757
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2758
idempotent.
2759
alters the names table, so it will need to be repopulated after running this function.
2760
';
2761

    
2762

    
2763
--
2764
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2765
--
2766

    
2767
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2768
    LANGUAGE sql
2769
    AS $_$
2770
SELECT util.drop_table($1);
2771
SELECT util.mk_map_table($1);
2772
$_$;
2773

    
2774

    
2775
--
2776
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2777
--
2778

    
2779
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2780
    LANGUAGE sql IMMUTABLE
2781
    AS $_$
2782
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2783
$_$;
2784

    
2785

    
2786
--
2787
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
2788
--
2789

    
2790
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2791
    LANGUAGE sql IMMUTABLE
2792
    AS $_$
2793
SELECT util.mk_set_search_path(for_printing := true)||$$;
2794
$$||$1
2795
$_$;
2796

    
2797

    
2798
--
2799
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2800
--
2801

    
2802
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2803
    LANGUAGE plpgsql STRICT
2804
    AS $_$
2805
DECLARE
2806
	result text = NULL;
2807
BEGIN
2808
	BEGIN
2809
		result = util.show_create_view(view_);
2810
		PERFORM util.eval($$DROP VIEW $$||view_);
2811
	EXCEPTION
2812
		WHEN undefined_table THEN NULL;
2813
	END;
2814
	RETURN result;
2815
END;
2816
$_$;
2817

    
2818

    
2819
--
2820
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2821
--
2822

    
2823
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2824
    LANGUAGE sql
2825
    AS $_$
2826
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2827
$_$;
2828

    
2829

    
2830
--
2831
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2832
--
2833

    
2834
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2835
    LANGUAGE sql STABLE
2836
    AS $_$
2837
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2838
$_$;
2839

    
2840

    
2841
--
2842
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2843
--
2844

    
2845
CREATE FUNCTION schema(table_ regclass) RETURNS text
2846
    LANGUAGE sql STABLE
2847
    AS $_$
2848
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2849
$_$;
2850

    
2851

    
2852
--
2853
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2854
--
2855

    
2856
CREATE FUNCTION schema(type regtype) RETURNS text
2857
    LANGUAGE sql STABLE
2858
    AS $_$
2859
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2860
$_$;
2861

    
2862

    
2863
--
2864
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2865
--
2866

    
2867
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2868
    LANGUAGE sql STABLE
2869
    AS $_$
2870
SELECT util.schema(pg_typeof($1))
2871
$_$;
2872

    
2873

    
2874
--
2875
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2876
--
2877

    
2878
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2879
    LANGUAGE sql STABLE
2880
    AS $_$
2881
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2882
$_$;
2883

    
2884

    
2885
--
2886
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2887
--
2888

    
2889
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2890
a schema bundle is a group of schemas with a common prefix
2891
';
2892

    
2893

    
2894
--
2895
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2896
--
2897

    
2898
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2899
    LANGUAGE sql
2900
    AS $_$
2901
SELECT util.schema_rename(old_schema,
2902
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2903
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2904
SELECT NULL::void; -- don't fold away functions called in previous query
2905
$_$;
2906

    
2907

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

    
2912
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2913
    LANGUAGE plpgsql
2914
    AS $$
2915
BEGIN
2916
	-- don't schema_bundle_rm() the schema_bundle to keep!
2917
	IF replace = with_ THEN RETURN; END IF;
2918
	
2919
	PERFORM util.schema_bundle_rm(replace);
2920
	PERFORM util.schema_bundle_rename(with_, replace);
2921
END;
2922
$$;
2923

    
2924

    
2925
--
2926
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2927
--
2928

    
2929
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2930
    LANGUAGE sql
2931
    AS $_$
2932
SELECT util.schema_rm(schema)
2933
FROM util.schema_bundle_get_schemas($1) f (schema);
2934
SELECT NULL::void; -- don't fold away functions called in previous query
2935
$_$;
2936

    
2937

    
2938
--
2939
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2940
--
2941

    
2942
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2943
    LANGUAGE sql STABLE
2944
    AS $_$
2945
SELECT quote_ident(util.schema($1))
2946
$_$;
2947

    
2948

    
2949
--
2950
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2951
--
2952

    
2953
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2954
    LANGUAGE sql IMMUTABLE
2955
    AS $_$
2956
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2957
$_$;
2958

    
2959

    
2960
--
2961
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2962
--
2963

    
2964
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2965
    LANGUAGE sql STABLE
2966
    AS $_$
2967
SELECT oid FROM pg_namespace WHERE nspname = $1
2968
$_$;
2969

    
2970

    
2971
--
2972
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2973
--
2974

    
2975
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2976
    LANGUAGE sql
2977
    AS $_$
2978
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2979
$_$;
2980

    
2981

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

    
2986
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2987
    LANGUAGE plpgsql
2988
    AS $$
2989
BEGIN
2990
	-- don't schema_rm() the schema to keep!
2991
	IF replace = with_ THEN RETURN; END IF;
2992
	
2993
	PERFORM util.schema_rm(replace);
2994
	PERFORM util.schema_rename(with_, replace);
2995
END;
2996
$$;
2997

    
2998

    
2999
--
3000
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3001
--
3002

    
3003
CREATE FUNCTION schema_rm(schema text) RETURNS void
3004
    LANGUAGE sql
3005
    AS $_$
3006
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3007
$_$;
3008

    
3009

    
3010
--
3011
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3012
--
3013

    
3014
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3015
    LANGUAGE sql
3016
    AS $_$
3017
SELECT util.eval(
3018
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3019
$_$;
3020

    
3021

    
3022
--
3023
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3024
--
3025

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

    
3042

    
3043
--
3044
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3045
--
3046

    
3047
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3048
idempotent
3049
';
3050

    
3051

    
3052
--
3053
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3054
--
3055

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

    
3083

    
3084
--
3085
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3086
--
3087

    
3088
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3089
idempotent.
3090
the metadata mappings must be *last* in the names table.
3091
';
3092

    
3093

    
3094
--
3095
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3096
--
3097

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

    
3124

    
3125
--
3126
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3127
--
3128

    
3129
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3130
idempotent
3131
';
3132

    
3133

    
3134
--
3135
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3136
--
3137

    
3138
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3139
    LANGUAGE sql
3140
    AS $_$
3141
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3142
$_$;
3143

    
3144

    
3145
--
3146
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3147
--
3148

    
3149
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3150
    LANGUAGE sql STABLE
3151
    AS $_$
3152
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3153
$$||util.show_grants_for($1)
3154
$_$;
3155

    
3156

    
3157
--
3158
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3159
--
3160

    
3161
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3162
    LANGUAGE sql STABLE
3163
    AS $_$
3164
SELECT string_agg(cmd, '')
3165
FROM
3166
(
3167
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3168
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3169
$$ ELSE '' END) AS cmd
3170
	FROM util.grants_users() f (user_)
3171
) s
3172
$_$;
3173

    
3174

    
3175
--
3176
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3177
--
3178

    
3179
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3180
    LANGUAGE sql STABLE
3181
    AS $_$
3182
SELECT oid FROM pg_class
3183
WHERE relkind = ANY($3) AND relname ~ $1
3184
AND util.schema_matches(util.schema(relnamespace), $2)
3185
ORDER BY relname
3186
$_$;
3187

    
3188

    
3189
--
3190
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3191
--
3192

    
3193
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3194
    LANGUAGE sql STABLE
3195
    AS $_$
3196
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3197
$_$;
3198

    
3199

    
3200
--
3201
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3202
--
3203

    
3204
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3205
    LANGUAGE sql IMMUTABLE
3206
    AS $_$
3207
SELECT '^'||util.regexp_quote($1)||'$'
3208
$_$;
3209

    
3210

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

    
3215
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3216
    LANGUAGE plpgsql STABLE STRICT
3217
    AS $_$
3218
DECLARE
3219
    hstore hstore;
3220
BEGIN
3221
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3222
        table_||$$))$$ INTO STRICT hstore;
3223
    RETURN hstore;
3224
END;
3225
$_$;
3226

    
3227

    
3228
--
3229
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3230
--
3231

    
3232
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3233
    LANGUAGE sql STABLE
3234
    AS $_$
3235
SELECT COUNT(*) > 0 FROM pg_constraint
3236
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3237
$_$;
3238

    
3239

    
3240
--
3241
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3242
--
3243

    
3244
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3245
gets whether a status flag is set by the presence of a table constraint
3246
';
3247

    
3248

    
3249
--
3250
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3251
--
3252

    
3253
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3254
    LANGUAGE sql
3255
    AS $_$
3256
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3257
||quote_ident($2)||$$ CHECK (true)$$)
3258
$_$;
3259

    
3260

    
3261
--
3262
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3263
--
3264

    
3265
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3266
stores a status flag by the presence of a table constraint.
3267
idempotent.
3268
';
3269

    
3270

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

    
3275
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3276
    LANGUAGE sql STABLE
3277
    AS $_$
3278
SELECT util.table_flag__get($1, 'nulls_mapped')
3279
$_$;
3280

    
3281

    
3282
--
3283
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3284
--
3285

    
3286
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3287
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3288
';
3289

    
3290

    
3291
--
3292
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3293
--
3294

    
3295
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3296
    LANGUAGE sql
3297
    AS $_$
3298
SELECT util.table_flag__set($1, 'nulls_mapped')
3299
$_$;
3300

    
3301

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

    
3306
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3307
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3308
idempotent.
3309
';
3310

    
3311

    
3312
--
3313
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3314
--
3315

    
3316
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3317
    LANGUAGE plpgsql STRICT
3318
    AS $_$
3319
DECLARE
3320
    row record;
3321
BEGIN
3322
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3323
    LOOP
3324
        IF row.global_name != row.name THEN
3325
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3326
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3327
        END IF;
3328
    END LOOP;
3329
END;
3330
$_$;
3331

    
3332

    
3333
--
3334
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3335
--
3336

    
3337
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3338
idempotent
3339
';
3340

    
3341

    
3342
--
3343
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3344
--
3345

    
3346
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3347
    LANGUAGE sql
3348
    AS $_$
3349
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3350
SELECT NULL::void; -- don't fold away functions called in previous query
3351
$_$;
3352

    
3353

    
3354
--
3355
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3356
--
3357

    
3358
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3359
trims table_ to include only columns in the original data.
3360
idempotent.
3361
';
3362

    
3363

    
3364
--
3365
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3366
--
3367

    
3368
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3369
    LANGUAGE plpgsql STRICT
3370
    AS $_$
3371
BEGIN
3372
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3373
END;
3374
$_$;
3375

    
3376

    
3377
--
3378
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3379
--
3380

    
3381
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3382
idempotent
3383
';
3384

    
3385

    
3386
--
3387
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3388
--
3389

    
3390
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3391
    LANGUAGE sql IMMUTABLE
3392
    AS $_$
3393
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3394
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3395
$_$;
3396

    
3397

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

    
3402
CREATE FUNCTION try_create(sql text) RETURNS void
3403
    LANGUAGE plpgsql STRICT
3404
    AS $$
3405
BEGIN
3406
    PERFORM util.eval(sql);
3407
EXCEPTION
3408
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3409
    WHEN undefined_column THEN NULL;
3410
    WHEN duplicate_column THEN NULL;
3411
END;
3412
$$;
3413

    
3414

    
3415
--
3416
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3417
--
3418

    
3419
COMMENT ON FUNCTION try_create(sql text) IS '
3420
idempotent
3421
';
3422

    
3423

    
3424
--
3425
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3426
--
3427

    
3428
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3429
    LANGUAGE sql
3430
    AS $_$
3431
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3432
$_$;
3433

    
3434

    
3435
--
3436
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3437
--
3438

    
3439
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3440
idempotent
3441
';
3442

    
3443

    
3444
--
3445
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3446
--
3447

    
3448
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3449
    LANGUAGE sql IMMUTABLE
3450
    AS $_$
3451
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3452
$_$;
3453

    
3454

    
3455
--
3456
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3457
--
3458

    
3459
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3460
a type''s NOT NULL qualifier
3461
';
3462

    
3463

    
3464
--
3465
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3466
--
3467

    
3468
CREATE FUNCTION typeof(value anyelement) RETURNS text
3469
    LANGUAGE sql IMMUTABLE
3470
    AS $_$
3471
SELECT util.qual_name(pg_typeof($1))
3472
$_$;
3473

    
3474

    
3475
--
3476
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3477
--
3478

    
3479
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3480
    LANGUAGE plpgsql STABLE
3481
    AS $_$
3482
DECLARE
3483
    type regtype;
3484
BEGIN
3485
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3486
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3487
    RETURN type;
3488
END;
3489
$_$;
3490

    
3491

    
3492
--
3493
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3494
--
3495

    
3496
CREATE AGGREGATE all_same(anyelement) (
3497
    SFUNC = all_same_transform,
3498
    STYPE = anyarray,
3499
    FINALFUNC = all_same_final
3500
);
3501

    
3502

    
3503
--
3504
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3505
--
3506

    
3507
COMMENT ON AGGREGATE all_same(anyelement) IS '
3508
includes NULLs in comparison
3509
';
3510

    
3511

    
3512
--
3513
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3514
--
3515

    
3516
CREATE AGGREGATE join_strs(text, text) (
3517
    SFUNC = join_strs_transform,
3518
    STYPE = text
3519
);
3520

    
3521

    
3522
--
3523
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3524
--
3525

    
3526
CREATE OPERATOR %== (
3527
    PROCEDURE = "%==",
3528
    LEFTARG = anyelement,
3529
    RIGHTARG = anyelement
3530
);
3531

    
3532

    
3533
--
3534
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3535
--
3536

    
3537
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3538
returns whether the map-keys of the compared values are the same
3539
(mnemonic: % is the Perl symbol for a hash map)
3540

    
3541
should be overridden for types that store both keys and values
3542

    
3543
used in a FULL JOIN to select which columns to join on
3544
';
3545

    
3546

    
3547
--
3548
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3549
--
3550

    
3551
CREATE OPERATOR -> (
3552
    PROCEDURE = map_get,
3553
    LEFTARG = regclass,
3554
    RIGHTARG = text
3555
);
3556

    
3557

    
3558
--
3559
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3560
--
3561

    
3562
CREATE OPERATOR => (
3563
    PROCEDURE = hstore,
3564
    LEFTARG = text[],
3565
    RIGHTARG = text
3566
);
3567

    
3568

    
3569
--
3570
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3571
--
3572

    
3573
COMMENT ON OPERATOR => (text[], text) IS '
3574
usage: array[''key1'', ...]::text[] => ''value''
3575
';
3576

    
3577

    
3578
--
3579
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3580
--
3581

    
3582
CREATE OPERATOR ?*>= (
3583
    PROCEDURE = is_populated_more_often_than,
3584
    LEFTARG = anyelement,
3585
    RIGHTARG = anyelement
3586
);
3587

    
3588

    
3589
--
3590
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3591
--
3592

    
3593
CREATE OPERATOR ?>= (
3594
    PROCEDURE = is_more_complete_than,
3595
    LEFTARG = anyelement,
3596
    RIGHTARG = anyelement
3597
);
3598

    
3599

    
3600
--
3601
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3602
--
3603

    
3604
CREATE OPERATOR ||% (
3605
    PROCEDURE = concat_esc,
3606
    LEFTARG = text,
3607
    RIGHTARG = text
3608
);
3609

    
3610

    
3611
--
3612
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3613
--
3614

    
3615
COMMENT ON OPERATOR ||% (text, text) IS '
3616
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3617
';
3618

    
3619

    
3620
--
3621
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3622
--
3623

    
3624
CREATE TABLE map (
3625
    "from" text NOT NULL,
3626
    "to" text,
3627
    filter text,
3628
    notes text
3629
);
3630

    
3631

    
3632
--
3633
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3634
--
3635

    
3636

    
3637

    
3638
--
3639
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3640
--
3641

    
3642

    
3643

    
3644
--
3645
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3646
--
3647

    
3648
ALTER TABLE ONLY map
3649
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3650

    
3651

    
3652
--
3653
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3654
--
3655

    
3656
ALTER TABLE ONLY map
3657
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3658

    
3659

    
3660
--
3661
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3662
--
3663

    
3664
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3665

    
3666

    
3667
--
3668
-- PostgreSQL database dump complete
3669
--
3670

    
(19-19/29)