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
    SET search_path TO pg_temp
1302
    AS $$
1303
/* function option search_path is needed to limit the effects of any
1304
`SET LOCAL search_path` to the current function */
1305
BEGIN
1306
	PERFORM util.debug_print_sql(sql);
1307
	RETURN QUERY EXECUTE sql;
1308
END;
1309
$$;
1310

    
1311

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

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

    
1320

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

    
1325
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1326
    LANGUAGE plpgsql
1327
    SET search_path TO pg_temp
1328
    AS $$
1329
/* function option search_path is needed to limit the effects of any
1330
`SET LOCAL search_path` to the current function */
1331
BEGIN
1332
	PERFORM util.debug_print_sql(sql);
1333
	RETURN QUERY EXECUTE sql;
1334
END;
1335
$$;
1336

    
1337

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

    
1342
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1343
    LANGUAGE plpgsql
1344
    SET search_path TO pg_temp
1345
    AS $$
1346
/* function option search_path is needed to limit the effects of any
1347
`SET LOCAL search_path` to the current function */
1348
BEGIN
1349
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1350
	RETURN QUERY EXECUTE sql;
1351
END;
1352
$$;
1353

    
1354

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

    
1359
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1360
    LANGUAGE plpgsql
1361
    SET search_path TO pg_temp
1362
    AS $$
1363
/* function option search_path is needed to limit the effects of any
1364
`SET LOCAL search_path` to the current function */
1365
DECLARE
1366
	ret_val ret_type_null%TYPE;
1367
BEGIN
1368
	PERFORM util.debug_print_sql(sql);
1369
	EXECUTE sql INTO STRICT ret_val;
1370
	RETURN ret_val;
1371
END;
1372
$$;
1373

    
1374

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

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

    
1383

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

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

    
1394

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

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

    
1403

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

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

    
1414

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

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

    
1424

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

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

    
1437

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

    
1442
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1443
    LANGUAGE sql
1444
    AS $_$
1445
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1446
$_$;
1447

    
1448

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

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

    
1459

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

    
1464
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1465
    LANGUAGE sql
1466
    AS $_$
1467
-- newline before and after to visually separate it from other debug info
1468
SELECT $$
1469
EXPLAIN:
1470
$$||util.explain2str($1)||$$
1471
$$
1472
$_$;
1473

    
1474

    
1475
--
1476
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1477
--
1478

    
1479
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1480
    LANGUAGE sql
1481
    AS $_$
1482
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1483
$_$;
1484

    
1485

    
1486
--
1487
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1488
--
1489

    
1490
CREATE FUNCTION explain2str(sql text) RETURNS text
1491
    LANGUAGE sql
1492
    AS $_$
1493
SELECT util.join_strs(explain, $$
1494
$$) FROM util.explain($1)
1495
$_$;
1496

    
1497

    
1498
SET default_tablespace = '';
1499

    
1500
SET default_with_oids = false;
1501

    
1502
--
1503
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1504
--
1505

    
1506
CREATE TABLE explain (
1507
    line text NOT NULL
1508
);
1509

    
1510

    
1511
--
1512
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1513
--
1514

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

    
1523

    
1524
--
1525
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1526
--
1527

    
1528
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1529
usage:
1530
PERFORM util.explain2table($$
1531
query
1532
$$);
1533
';
1534

    
1535

    
1536
--
1537
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1538
--
1539

    
1540
CREATE FUNCTION first_word(str text) RETURNS text
1541
    LANGUAGE sql IMMUTABLE
1542
    AS $_$
1543
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1544
$_$;
1545

    
1546

    
1547
--
1548
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1549
--
1550

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

    
1559

    
1560
--
1561
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1562
--
1563

    
1564
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1565
ensures that an array will always have proper non-NULL dimensions
1566
';
1567

    
1568

    
1569
--
1570
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1571
--
1572

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

    
1593

    
1594
--
1595
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1596
--
1597

    
1598
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1599
idempotent
1600

    
1601
users: not necessary to provide this because it will be autopopulated
1602
';
1603

    
1604

    
1605
--
1606
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1607
--
1608

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

    
1629

    
1630
--
1631
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1632
--
1633

    
1634
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1635
idempotent
1636
';
1637

    
1638

    
1639
--
1640
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1641
--
1642

    
1643
CREATE FUNCTION grants_users() RETURNS SETOF text
1644
    LANGUAGE sql IMMUTABLE
1645
    AS $$
1646
VALUES ('bien_read'), ('public_')
1647
$$;
1648

    
1649

    
1650
--
1651
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1652
--
1653

    
1654
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1655
    LANGUAGE sql IMMUTABLE
1656
    AS $_$
1657
SELECT substring($2 for length($1)) = $1
1658
$_$;
1659

    
1660

    
1661
--
1662
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1663
--
1664

    
1665
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1666
    LANGUAGE sql STABLE
1667
    AS $_$
1668
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1669
$_$;
1670

    
1671

    
1672
--
1673
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1674
--
1675

    
1676
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1677
    LANGUAGE sql IMMUTABLE
1678
    AS $_$
1679
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1680
$_$;
1681

    
1682

    
1683
--
1684
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1685
--
1686

    
1687
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1688
avoids repeating the same value for each key
1689
';
1690

    
1691

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

    
1696
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1697
    LANGUAGE sql IMMUTABLE
1698
    AS $_$
1699
SELECT COALESCE($1, $2)
1700
$_$;
1701

    
1702

    
1703
--
1704
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1705
--
1706

    
1707
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1708
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1709
';
1710

    
1711

    
1712
--
1713
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1714
--
1715

    
1716
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1717
    LANGUAGE sql
1718
    AS $_$
1719
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1720
$_$;
1721

    
1722

    
1723
--
1724
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1725
--
1726

    
1727
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1728
    LANGUAGE sql STABLE
1729
    AS $_$
1730
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1731
$_$;
1732

    
1733

    
1734
--
1735
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1736
--
1737

    
1738
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1739
    LANGUAGE sql IMMUTABLE
1740
    AS $_$
1741
SELECT util.array_length($1) = 0
1742
$_$;
1743

    
1744

    
1745
--
1746
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1747
--
1748

    
1749
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1750
    LANGUAGE sql IMMUTABLE
1751
    AS $_$
1752
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1753
$_$;
1754

    
1755

    
1756
--
1757
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1758
--
1759

    
1760
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1761
    LANGUAGE sql IMMUTABLE
1762
    AS $_$
1763
SELECT upper(util.first_word($1)) = ANY(
1764
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1765
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1766
)
1767
$_$;
1768

    
1769

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

    
1774
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1775
    LANGUAGE sql IMMUTABLE
1776
    AS $_$
1777
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1778
$_$;
1779

    
1780

    
1781
--
1782
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1783
--
1784

    
1785
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1786
    LANGUAGE sql IMMUTABLE
1787
    AS $_$
1788
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1789
$_$;
1790

    
1791

    
1792
--
1793
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1794
--
1795

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

    
1802

    
1803
--
1804
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1805
--
1806

    
1807
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1808
    LANGUAGE sql STABLE
1809
    AS $_$
1810
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1811
$_$;
1812

    
1813

    
1814
--
1815
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1816
--
1817

    
1818
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1819
    LANGUAGE sql IMMUTABLE STRICT
1820
    AS $_$
1821
SELECT $1 || $3 || $2
1822
$_$;
1823

    
1824

    
1825
--
1826
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1827
--
1828

    
1829
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1830
must be declared STRICT to use the special handling of STRICT aggregating functions
1831
';
1832

    
1833

    
1834
--
1835
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1836
--
1837

    
1838
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1839
    LANGUAGE sql IMMUTABLE
1840
    AS $_$
1841
SELECT $1 -- compare on the entire value
1842
$_$;
1843

    
1844

    
1845
--
1846
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1847
--
1848

    
1849
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1850
    LANGUAGE sql IMMUTABLE
1851
    AS $_$
1852
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1853
$_$;
1854

    
1855

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

    
1860
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1861
    LANGUAGE sql IMMUTABLE
1862
    AS $_$
1863
SELECT ltrim($1, $$
1864
$$)
1865
$_$;
1866

    
1867

    
1868
--
1869
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1870
--
1871

    
1872
CREATE FUNCTION map_filter_insert() RETURNS trigger
1873
    LANGUAGE plpgsql
1874
    AS $$
1875
BEGIN
1876
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1877
	RETURN new;
1878
END;
1879
$$;
1880

    
1881

    
1882
--
1883
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1884
--
1885

    
1886
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1887
    LANGUAGE plpgsql STABLE STRICT
1888
    AS $_$
1889
DECLARE
1890
    value text;
1891
BEGIN
1892
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1893
        INTO value USING key;
1894
    RETURN value;
1895
END;
1896
$_$;
1897

    
1898

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

    
1903
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1904
    LANGUAGE sql IMMUTABLE
1905
    AS $_$
1906
SELECT util._map(util.nulls_map($1), $2)
1907
$_$;
1908

    
1909

    
1910
--
1911
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1912
--
1913

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

    
1917
[1] inlining of function calls, which is different from constant folding
1918
[2] _map()''s profiling query
1919
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1920
and map_nulls()''s profiling query
1921
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1922
both take ~920 ms.
1923
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.
1924
';
1925

    
1926

    
1927
--
1928
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1929
--
1930

    
1931
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1932
    LANGUAGE plpgsql STABLE STRICT
1933
    AS $_$
1934
BEGIN
1935
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1936
END;
1937
$_$;
1938

    
1939

    
1940
--
1941
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1942
--
1943

    
1944
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1945
    LANGUAGE sql
1946
    AS $_$
1947
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1948
$$||util.ltrim_nl($2));
1949
-- make sure the created table has the correct estimated row count
1950
SELECT util.analyze_($1);
1951

    
1952
SELECT util.append_comment($1, '
1953
contents generated from:
1954
'||util.ltrim_nl($2)||';
1955
');
1956
$_$;
1957

    
1958

    
1959
--
1960
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
1961
--
1962

    
1963
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
1964
idempotent
1965
';
1966

    
1967

    
1968
--
1969
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1970
--
1971

    
1972
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
1973
    LANGUAGE sql
1974
    AS $_$
1975
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1976
$_$;
1977

    
1978

    
1979
--
1980
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1981
--
1982

    
1983
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
1984
idempotent
1985
';
1986

    
1987

    
1988
--
1989
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1990
--
1991

    
1992
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1993
    LANGUAGE sql
1994
    AS $_$
1995
SELECT util.create_if_not_exists($$
1996
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1997
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1998
||quote_literal($2)||$$;
1999
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2000
constant
2001
';
2002
$$)
2003
$_$;
2004

    
2005

    
2006
--
2007
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2008
--
2009

    
2010
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2011
idempotent
2012
';
2013

    
2014

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

    
2019
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2020
    LANGUAGE plpgsql STRICT
2021
    AS $_$
2022
DECLARE
2023
    type regtype = util.typeof(expr, col.table_::text::regtype);
2024
    col_name_sql text = quote_ident(col.name);
2025
BEGIN
2026
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2027
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2028
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2029
$$||expr||$$;
2030
$$);
2031
END;
2032
$_$;
2033

    
2034

    
2035
--
2036
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2037
--
2038

    
2039
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2040
idempotent
2041
';
2042

    
2043

    
2044
--
2045
-- Name: mk_diff_query(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2046
--
2047

    
2048
CREATE FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean DEFAULT false) RETURNS text
2049
    LANGUAGE sql IMMUTABLE
2050
    AS $_$
2051
SELECT
2052
$$SELECT left_, right_
2053
FROM $$||$1||$$ left_
2054
$$||util._if($3, 'CROSS'::text, 'FULL')||$$ JOIN $$||$2||$$ right_
2055
$$||util._if($3, ''::text,
2056
$$ON left_ %== right_ -- refer to EXPLAIN output for expansion of %==
2057
$$)||
2058
$$WHERE left_ IS DISTINCT FROM right_
2059
ORDER BY left_, right_
2060
$$
2061
$_$;
2062

    
2063

    
2064
--
2065
-- Name: FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean); Type: COMMENT; Schema: util; Owner: -
2066
--
2067

    
2068
COMMENT ON FUNCTION mk_diff_query(left_ text, right_ text, single_row boolean) IS '
2069
single_row: whether the tables consist of a single row, which should be
2070
	displayed side-by-side
2071
';
2072

    
2073

    
2074
--
2075
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2076
--
2077

    
2078
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2079
    LANGUAGE sql
2080
    AS $_$
2081
SELECT util.create_if_not_exists($$
2082
CREATE TABLE $$||$1||$$
2083
(
2084
    LIKE util.map INCLUDING ALL
2085
);
2086

    
2087
CREATE TRIGGER map_filter_insert
2088
  BEFORE INSERT
2089
  ON $$||$1||$$
2090
  FOR EACH ROW
2091
  EXECUTE PROCEDURE util.map_filter_insert();
2092
$$)
2093
$_$;
2094

    
2095

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

    
2100
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2101
    LANGUAGE sql IMMUTABLE
2102
    AS $_$
2103
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
2104
$_$;
2105

    
2106

    
2107
--
2108
-- Name: mk_set_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2109
--
2110

    
2111
CREATE FUNCTION mk_set_search_path(VARIADIC schemas text[]) RETURNS text
2112
    LANGUAGE sql IMMUTABLE
2113
    AS $_$
2114
SELECT util.mk_set_search_path(util.mk_search_path(VARIADIC $1))
2115
$_$;
2116

    
2117

    
2118
--
2119
-- Name: FUNCTION mk_set_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2120
--
2121

    
2122
COMMENT ON FUNCTION mk_set_search_path(VARIADIC schemas text[]) IS '
2123
usage:
2124
for *1* schema arg:
2125
SELECT util.mk_set_search_path(''schema'', NULL) AS search_path;
2126
	-- 2 params are needed to use the correct variant of mk_set_search_path()
2127
';
2128

    
2129

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

    
2134
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2135
    LANGUAGE sql IMMUTABLE
2136
    AS $_$
2137
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2138
$_$;
2139

    
2140

    
2141
--
2142
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2143
--
2144

    
2145
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2146
    LANGUAGE sql IMMUTABLE
2147
    AS $_$
2148
/* debug_print_return_value() needed because this function is used with EXECUTE
2149
rather than util.eval() (in order to affect the calling function), so the
2150
search_path would not otherwise be printed */
2151
SELECT util.debug_print_return_value($$SET$$
2152
||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$) ||$$ search_path TO $$||$1)
2153
$_$;
2154

    
2155

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

    
2160
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2161
    LANGUAGE sql
2162
    AS $_$
2163
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2164
$_$;
2165

    
2166

    
2167
--
2168
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2169
--
2170

    
2171
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2172
idempotent
2173
';
2174

    
2175

    
2176
--
2177
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2178
--
2179

    
2180
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2181
    LANGUAGE plpgsql STRICT
2182
    AS $_$
2183
DECLARE
2184
	view_qual_name text = util.qual_name(view_);
2185
BEGIN
2186
	EXECUTE $$
2187
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2188
  RETURNS SETOF $$||view_||$$ AS
2189
$BODY1$
2190
SELECT * FROM $$||view_qual_name||$$
2191
ORDER BY sort_col
2192
LIMIT $1 OFFSET $2
2193
$BODY1$
2194
  LANGUAGE sql STABLE
2195
  COST 100
2196
  ROWS 1000
2197
$$;
2198
	
2199
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2200
END;
2201
$_$;
2202

    
2203

    
2204
--
2205
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2206
--
2207

    
2208
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2209
    LANGUAGE plpgsql STRICT
2210
    AS $_$
2211
DECLARE
2212
	view_qual_name text = util.qual_name(view_);
2213
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2214
BEGIN
2215
	EXECUTE $$
2216
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2217
  RETURNS integer AS
2218
$BODY1$
2219
SELECT $$||quote_ident(row_num_col)||$$
2220
FROM $$||view_qual_name||$$
2221
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2222
LIMIT 1
2223
$BODY1$
2224
  LANGUAGE sql STABLE
2225
  COST 100;
2226
$$;
2227
	
2228
	EXECUTE $$
2229
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2230
  RETURNS SETOF $$||view_||$$ AS
2231
$BODY1$
2232
SELECT * FROM $$||view_qual_name||$$
2233
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2234
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2235
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2236
ORDER BY $$||quote_ident(row_num_col)||$$
2237
$BODY1$
2238
  LANGUAGE sql STABLE
2239
  COST 100
2240
  ROWS 1000
2241
$$;
2242
	
2243
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2244
END;
2245
$_$;
2246

    
2247

    
2248
--
2249
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2250
--
2251

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

    
2280

    
2281
--
2282
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2283
--
2284

    
2285
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2286
creates subset function which turns off enable_sort
2287
';
2288

    
2289

    
2290
--
2291
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2292
--
2293

    
2294
CREATE FUNCTION mk_use_own_schema(schema_anchor anyelement) RETURNS text
2295
    LANGUAGE sql IMMUTABLE
2296
    AS $_$
2297
SELECT util.mk_set_search_path(util.schema_esc($1))
2298
$_$;
2299

    
2300

    
2301
--
2302
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2303
--
2304

    
2305
CREATE FUNCTION name(table_ regclass) RETURNS text
2306
    LANGUAGE sql STABLE
2307
    AS $_$
2308
SELECT relname::text FROM pg_class WHERE oid = $1
2309
$_$;
2310

    
2311

    
2312
--
2313
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2314
--
2315

    
2316
CREATE FUNCTION name(type regtype) RETURNS text
2317
    LANGUAGE sql STABLE
2318
    AS $_$
2319
SELECT typname::text FROM pg_type WHERE oid = $1
2320
$_$;
2321

    
2322

    
2323
--
2324
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2325
--
2326

    
2327
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2328
    LANGUAGE sql IMMUTABLE
2329
    AS $_$
2330
SELECT octet_length($1) >= util.namedatalen() - $2
2331
$_$;
2332

    
2333

    
2334
--
2335
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2336
--
2337

    
2338
CREATE FUNCTION namedatalen() RETURNS integer
2339
    LANGUAGE sql IMMUTABLE
2340
    AS $$
2341
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2342
$$;
2343

    
2344

    
2345
--
2346
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2347
--
2348

    
2349
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2350
    LANGUAGE sql IMMUTABLE
2351
    AS $_$
2352
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2353
$_$;
2354

    
2355

    
2356
--
2357
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2358
--
2359

    
2360
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2361
    LANGUAGE sql IMMUTABLE
2362
    AS $_$
2363
SELECT $1 IS NOT NULL
2364
$_$;
2365

    
2366

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

    
2371
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2372
    LANGUAGE sql IMMUTABLE
2373
    AS $_$
2374
SELECT util.hstore($1, NULL) || '*=>*'
2375
$_$;
2376

    
2377

    
2378
--
2379
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2380
--
2381

    
2382
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2383
for use with _map()
2384
';
2385

    
2386

    
2387
--
2388
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2389
--
2390

    
2391
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2392
    LANGUAGE sql IMMUTABLE
2393
    AS $_$
2394
SELECT $2 + COALESCE($1, 0)
2395
$_$;
2396

    
2397

    
2398
--
2399
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2400
--
2401

    
2402
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2403
    LANGUAGE sql IMMUTABLE
2404
    AS $_$
2405
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2406
$_$;
2407

    
2408

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

    
2413
CREATE FUNCTION qual_name(table_ regclass) 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: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2423
--
2424

    
2425
CREATE FUNCTION qual_name(type regtype) RETURNS text
2426
    LANGUAGE sql STABLE
2427
    SET search_path TO pg_temp
2428
    AS $_$
2429
SELECT $1::text
2430
$_$;
2431

    
2432

    
2433
--
2434
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2435
--
2436

    
2437
COMMENT ON FUNCTION qual_name(type regtype) IS '
2438
a type''s schema-qualified name
2439
';
2440

    
2441

    
2442
--
2443
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2444
--
2445

    
2446
CREATE FUNCTION qual_name(type unknown) RETURNS text
2447
    LANGUAGE sql STABLE
2448
    AS $_$
2449
SELECT util.qual_name($1::text::regtype)
2450
$_$;
2451

    
2452

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

    
2457
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2458
    LANGUAGE sql IMMUTABLE
2459
    AS $_$
2460
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2461
$_$;
2462

    
2463

    
2464
--
2465
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2466
--
2467

    
2468
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2469
    LANGUAGE sql IMMUTABLE
2470
    AS $_$
2471
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2472
$_$;
2473

    
2474

    
2475
--
2476
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2477
--
2478

    
2479
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2480
    LANGUAGE sql IMMUTABLE
2481
    AS $_$
2482
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2483
$_$;
2484

    
2485

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

    
2490
CREATE FUNCTION raise_error_notice(msg text) RETURNS void
2491
    LANGUAGE sql IMMUTABLE
2492
    AS $_$
2493
SELECT util.raise_notice('ERROR:  '||$1)
2494
$_$;
2495

    
2496

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

    
2501
CREATE FUNCTION raise_notice(msg text) RETURNS void
2502
    LANGUAGE plpgsql IMMUTABLE STRICT
2503
    AS $$
2504
BEGIN
2505
	RAISE NOTICE '%', msg;
2506
END;
2507
$$;
2508

    
2509

    
2510
--
2511
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2512
--
2513

    
2514
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2515
    LANGUAGE plpgsql IMMUTABLE STRICT
2516
    AS $$
2517
BEGIN
2518
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2519
END;
2520
$$;
2521

    
2522

    
2523
--
2524
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2525
--
2526

    
2527
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2528
    LANGUAGE sql IMMUTABLE
2529
    AS $_$
2530
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2531
$_$;
2532

    
2533

    
2534
--
2535
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2536
--
2537

    
2538
CREATE FUNCTION regexp_quote(str text) RETURNS text
2539
    LANGUAGE sql IMMUTABLE
2540
    AS $_$
2541
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2542
$_$;
2543

    
2544

    
2545
--
2546
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2547
--
2548

    
2549
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2550
    LANGUAGE sql IMMUTABLE
2551
    AS $_$
2552
SELECT (CASE WHEN right($1, 1) = ')'
2553
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2554
$_$;
2555

    
2556

    
2557
--
2558
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2559
--
2560

    
2561
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2562
    LANGUAGE sql STABLE
2563
    AS $_$
2564
SELECT util.relation_type(util.relation_type_char($1))
2565
$_$;
2566

    
2567

    
2568
--
2569
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2570
--
2571

    
2572
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2573
    LANGUAGE sql IMMUTABLE
2574
    AS $_$
2575
SELECT 'r=>TABLE, v=>VIEW'::hstore -> $1
2576
$_$;
2577

    
2578

    
2579
--
2580
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2581
--
2582

    
2583
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2584
    LANGUAGE sql STABLE
2585
    AS $_$
2586
SELECT relkind FROM pg_class WHERE oid = $1
2587
$_$;
2588

    
2589

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

    
2594
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2595
    LANGUAGE sql
2596
    AS $_$
2597
/* can't have in_table/out_table inherit from *each other*, because inheritance
2598
also causes the rows of the parent table to be included in the child table.
2599
instead, they need to inherit from a common, empty table. */
2600
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2601
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2602
SELECT util.inherit($2, $4);
2603
SELECT util.inherit($3, $4);
2604

    
2605
SELECT util.rematerialize_query($1, $$
2606
SELECT * FROM util.diff(
2607
  $$||util.quote_typed($2)||$$
2608
, $$||util.quote_typed($3)||$$
2609
, NULL::$$||$4||$$)
2610
$$);
2611

    
2612
/* the table unfortunately cannot be *materialized* in human-readable form,
2613
because this would create column name collisions between the two sides */
2614
SELECT util.append_comment($1, '
2615
to view this table in human-readable form (with each side''s tuple column
2616
expanded to its component fields):
2617
SELECT (left_).*, (right_).* FROM '||$1||';
2618
');
2619
$_$;
2620

    
2621

    
2622
--
2623
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2624
--
2625

    
2626
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2627
type_table (*required*): table to create as the shared base type
2628
';
2629

    
2630

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

    
2635
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2636
    LANGUAGE sql
2637
    AS $_$
2638
SELECT util.drop_table($1);
2639
SELECT util.materialize_query($1, $2);
2640
$_$;
2641

    
2642

    
2643
--
2644
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2645
--
2646

    
2647
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2648
idempotent, but repeats action each time
2649
';
2650

    
2651

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

    
2656
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2657
    LANGUAGE sql
2658
    AS $_$
2659
SELECT util.drop_table($1);
2660
SELECT util.materialize_view($1, $2);
2661
$_$;
2662

    
2663

    
2664
--
2665
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2666
--
2667

    
2668
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2669
idempotent, but repeats action each time
2670
';
2671

    
2672

    
2673
--
2674
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2675
--
2676

    
2677
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2678
    LANGUAGE sql
2679
    AS $_$
2680
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2681
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2682
FROM util.col_names($1::text::regtype) f (name);
2683
SELECT NULL::void; -- don't fold away functions called in previous query
2684
$_$;
2685

    
2686

    
2687
--
2688
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2689
--
2690

    
2691
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2692
idempotent
2693
';
2694

    
2695

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

    
2700
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2701
    LANGUAGE sql
2702
    AS $_$
2703
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2704
included in the debug SQL */
2705
SELECT util.rename_relation(util.qual_name($1), $2)
2706
$_$;
2707

    
2708

    
2709
--
2710
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2711
--
2712

    
2713
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2714
    LANGUAGE sql
2715
    AS $_$
2716
/* 'ALTER TABLE can be used with views too'
2717
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2718
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2719
||quote_ident($2))
2720
$_$;
2721

    
2722

    
2723
--
2724
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2725
--
2726

    
2727
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2728
idempotent
2729
';
2730

    
2731

    
2732
--
2733
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2734
--
2735

    
2736
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2737
    LANGUAGE sql IMMUTABLE
2738
    AS $_$
2739
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2740
$_$;
2741

    
2742

    
2743
--
2744
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2745
--
2746

    
2747
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2748
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 
2749
';
2750

    
2751

    
2752
--
2753
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2754
--
2755

    
2756
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2757
    LANGUAGE sql
2758
    AS $_$
2759
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2760
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2761
SELECT util.set_col_names($1, $2);
2762
$_$;
2763

    
2764

    
2765
--
2766
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2767
--
2768

    
2769
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2770
idempotent.
2771
alters the names table, so it will need to be repopulated after running this function.
2772
';
2773

    
2774

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

    
2779
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2780
    LANGUAGE sql
2781
    AS $_$
2782
SELECT util.drop_table($1);
2783
SELECT util.mk_map_table($1);
2784
$_$;
2785

    
2786

    
2787
--
2788
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2789
--
2790

    
2791
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2792
    LANGUAGE sql IMMUTABLE
2793
    AS $_$
2794
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2795
$_$;
2796

    
2797

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

    
2802
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2803
    LANGUAGE sql IMMUTABLE
2804
    AS $_$
2805
SELECT util.mk_set_search_path(for_printing := true)||$$;
2806
$$||$1
2807
$_$;
2808

    
2809

    
2810
--
2811
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2812
--
2813

    
2814
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2815
    LANGUAGE plpgsql STRICT
2816
    AS $_$
2817
DECLARE
2818
	result text = NULL;
2819
BEGIN
2820
	BEGIN
2821
		result = util.show_create_view(view_);
2822
		PERFORM util.eval($$DROP VIEW $$||view_);
2823
	EXCEPTION
2824
		WHEN undefined_table THEN NULL;
2825
	END;
2826
	RETURN result;
2827
END;
2828
$_$;
2829

    
2830

    
2831
--
2832
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
2833
--
2834

    
2835
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2836
    LANGUAGE sql
2837
    AS $_$
2838
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
2839
$_$;
2840

    
2841

    
2842
--
2843
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2844
--
2845

    
2846
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2847
    LANGUAGE sql STABLE
2848
    AS $_$
2849
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2850
$_$;
2851

    
2852

    
2853
--
2854
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2855
--
2856

    
2857
CREATE FUNCTION schema(table_ regclass) RETURNS text
2858
    LANGUAGE sql STABLE
2859
    AS $_$
2860
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2861
$_$;
2862

    
2863

    
2864
--
2865
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2866
--
2867

    
2868
CREATE FUNCTION schema(type regtype) RETURNS text
2869
    LANGUAGE sql STABLE
2870
    AS $_$
2871
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2872
$_$;
2873

    
2874

    
2875
--
2876
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2877
--
2878

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

    
2885

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

    
2890
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2891
    LANGUAGE sql STABLE
2892
    AS $_$
2893
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2894
$_$;
2895

    
2896

    
2897
--
2898
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2899
--
2900

    
2901
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2902
a schema bundle is a group of schemas with a common prefix
2903
';
2904

    
2905

    
2906
--
2907
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2908
--
2909

    
2910
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2911
    LANGUAGE sql
2912
    AS $_$
2913
SELECT util.schema_rename(old_schema,
2914
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2915
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2916
SELECT NULL::void; -- don't fold away functions called in previous query
2917
$_$;
2918

    
2919

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

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

    
2936

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

    
2941
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2942
    LANGUAGE sql
2943
    AS $_$
2944
SELECT util.schema_rm(schema)
2945
FROM util.schema_bundle_get_schemas($1) f (schema);
2946
SELECT NULL::void; -- don't fold away functions called in previous query
2947
$_$;
2948

    
2949

    
2950
--
2951
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2952
--
2953

    
2954
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2955
    LANGUAGE sql STABLE
2956
    AS $_$
2957
SELECT quote_ident(util.schema($1))
2958
$_$;
2959

    
2960

    
2961
--
2962
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
2963
--
2964

    
2965
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
2966
    LANGUAGE sql IMMUTABLE
2967
    AS $_$
2968
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
2969
$_$;
2970

    
2971

    
2972
--
2973
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2974
--
2975

    
2976
CREATE FUNCTION schema_oid(schema text) RETURNS oid
2977
    LANGUAGE sql STABLE
2978
    AS $_$
2979
SELECT oid FROM pg_namespace WHERE nspname = $1
2980
$_$;
2981

    
2982

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

    
2987
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2988
    LANGUAGE sql
2989
    AS $_$
2990
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2991
$_$;
2992

    
2993

    
2994
--
2995
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2996
--
2997

    
2998
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2999
    LANGUAGE plpgsql
3000
    AS $$
3001
BEGIN
3002
	-- don't schema_rm() the schema to keep!
3003
	IF replace = with_ THEN RETURN; END IF;
3004
	
3005
	PERFORM util.schema_rm(replace);
3006
	PERFORM util.schema_rename(with_, replace);
3007
END;
3008
$$;
3009

    
3010

    
3011
--
3012
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3013
--
3014

    
3015
CREATE FUNCTION schema_rm(schema text) RETURNS void
3016
    LANGUAGE sql
3017
    AS $_$
3018
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3019
$_$;
3020

    
3021

    
3022
--
3023
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3024
--
3025

    
3026
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3027
    LANGUAGE sql
3028
    AS $_$
3029
SELECT util.eval(
3030
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3031
$_$;
3032

    
3033

    
3034
--
3035
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3036
--
3037

    
3038
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3039
    LANGUAGE plpgsql STRICT
3040
    AS $_$
3041
DECLARE
3042
    old text[] = ARRAY(SELECT util.col_names(table_));
3043
    new text[] = ARRAY(SELECT util.map_values(names));
3044
BEGIN
3045
    old = old[1:array_length(new, 1)]; -- truncate to same length
3046
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3047
||$$ TO $$||quote_ident(value))
3048
    FROM each(hstore(old, new))
3049
    WHERE value != key -- not same name
3050
    ;
3051
END;
3052
$_$;
3053

    
3054

    
3055
--
3056
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3057
--
3058

    
3059
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3060
idempotent
3061
';
3062

    
3063

    
3064
--
3065
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3066
--
3067

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

    
3095

    
3096
--
3097
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3098
--
3099

    
3100
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3101
idempotent.
3102
the metadata mappings must be *last* in the names table.
3103
';
3104

    
3105

    
3106
--
3107
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3108
--
3109

    
3110
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3111
    LANGUAGE plpgsql STRICT
3112
    AS $_$
3113
DECLARE
3114
    sql text = $$ALTER TABLE $$||table_||$$
3115
$$||NULLIF(array_to_string(ARRAY(
3116
    SELECT
3117
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3118
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3119
    FROM
3120
    (
3121
        SELECT
3122
          quote_ident(col_name) AS col_name_sql
3123
        , util.col_type((table_, col_name)) AS curr_type
3124
        , type AS target_type
3125
        FROM unnest(col_casts)
3126
    ) s
3127
    WHERE curr_type != target_type
3128
), '
3129
, '), '');
3130
BEGIN
3131
    PERFORM util.debug_print_sql(sql);
3132
    EXECUTE COALESCE(sql, '');
3133
END;
3134
$_$;
3135

    
3136

    
3137
--
3138
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3139
--
3140

    
3141
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3142
idempotent
3143
';
3144

    
3145

    
3146
--
3147
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3148
--
3149

    
3150
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3151
    LANGUAGE sql
3152
    AS $_$
3153
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3154
$_$;
3155

    
3156

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

    
3161
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3162
    LANGUAGE sql STABLE
3163
    AS $_$
3164
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3165
$$||util.show_grants_for($1)
3166
$_$;
3167

    
3168

    
3169
--
3170
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3171
--
3172

    
3173
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3174
    LANGUAGE sql STABLE
3175
    AS $_$
3176
SELECT string_agg(cmd, '')
3177
FROM
3178
(
3179
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3180
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3181
$$ ELSE '' END) AS cmd
3182
	FROM util.grants_users() f (user_)
3183
) s
3184
$_$;
3185

    
3186

    
3187
--
3188
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3189
--
3190

    
3191
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3192
    LANGUAGE sql STABLE
3193
    AS $_$
3194
SELECT oid FROM pg_class
3195
WHERE relkind = ANY($3) AND relname ~ $1
3196
AND util.schema_matches(util.schema(relnamespace), $2)
3197
ORDER BY relname
3198
$_$;
3199

    
3200

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

    
3205
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3206
    LANGUAGE sql STABLE
3207
    AS $_$
3208
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3209
$_$;
3210

    
3211

    
3212
--
3213
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3214
--
3215

    
3216
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3217
    LANGUAGE sql IMMUTABLE
3218
    AS $_$
3219
SELECT '^'||util.regexp_quote($1)||'$'
3220
$_$;
3221

    
3222

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

    
3227
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3228
    LANGUAGE plpgsql STABLE STRICT
3229
    AS $_$
3230
DECLARE
3231
    hstore hstore;
3232
BEGIN
3233
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3234
        table_||$$))$$ INTO STRICT hstore;
3235
    RETURN hstore;
3236
END;
3237
$_$;
3238

    
3239

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

    
3244
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3245
    LANGUAGE sql STABLE
3246
    AS $_$
3247
SELECT COUNT(*) > 0 FROM pg_constraint
3248
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3249
$_$;
3250

    
3251

    
3252
--
3253
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3254
--
3255

    
3256
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3257
gets whether a status flag is set by the presence of a table constraint
3258
';
3259

    
3260

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

    
3265
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3266
    LANGUAGE sql
3267
    AS $_$
3268
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3269
||quote_ident($2)||$$ CHECK (true)$$)
3270
$_$;
3271

    
3272

    
3273
--
3274
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3275
--
3276

    
3277
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3278
stores a status flag by the presence of a table constraint.
3279
idempotent.
3280
';
3281

    
3282

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

    
3287
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3288
    LANGUAGE sql STABLE
3289
    AS $_$
3290
SELECT util.table_flag__get($1, 'nulls_mapped')
3291
$_$;
3292

    
3293

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

    
3298
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3299
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3300
';
3301

    
3302

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

    
3307
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3308
    LANGUAGE sql
3309
    AS $_$
3310
SELECT util.table_flag__set($1, 'nulls_mapped')
3311
$_$;
3312

    
3313

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

    
3318
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3319
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3320
idempotent.
3321
';
3322

    
3323

    
3324
--
3325
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3326
--
3327

    
3328
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3329
    LANGUAGE plpgsql STRICT
3330
    AS $_$
3331
DECLARE
3332
    row record;
3333
BEGIN
3334
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3335
    LOOP
3336
        IF row.global_name != row.name THEN
3337
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3338
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3339
        END IF;
3340
    END LOOP;
3341
END;
3342
$_$;
3343

    
3344

    
3345
--
3346
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3347
--
3348

    
3349
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3350
idempotent
3351
';
3352

    
3353

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

    
3358
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3359
    LANGUAGE sql
3360
    AS $_$
3361
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3362
SELECT NULL::void; -- don't fold away functions called in previous query
3363
$_$;
3364

    
3365

    
3366
--
3367
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3368
--
3369

    
3370
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3371
trims table_ to include only columns in the original data.
3372
idempotent.
3373
';
3374

    
3375

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

    
3380
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3381
    LANGUAGE plpgsql STRICT
3382
    AS $_$
3383
BEGIN
3384
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3385
END;
3386
$_$;
3387

    
3388

    
3389
--
3390
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3391
--
3392

    
3393
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3394
idempotent
3395
';
3396

    
3397

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

    
3402
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3403
    LANGUAGE sql IMMUTABLE
3404
    AS $_$
3405
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3406
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3407
$_$;
3408

    
3409

    
3410
--
3411
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3412
--
3413

    
3414
CREATE FUNCTION try_create(sql text) RETURNS void
3415
    LANGUAGE plpgsql STRICT
3416
    AS $$
3417
BEGIN
3418
    PERFORM util.eval(sql);
3419
EXCEPTION
3420
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3421
    WHEN undefined_column THEN NULL;
3422
    WHEN duplicate_column THEN NULL;
3423
END;
3424
$$;
3425

    
3426

    
3427
--
3428
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3429
--
3430

    
3431
COMMENT ON FUNCTION try_create(sql text) IS '
3432
idempotent
3433
';
3434

    
3435

    
3436
--
3437
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3438
--
3439

    
3440
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3441
    LANGUAGE sql
3442
    AS $_$
3443
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3444
$_$;
3445

    
3446

    
3447
--
3448
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3449
--
3450

    
3451
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3452
idempotent
3453
';
3454

    
3455

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

    
3460
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3461
    LANGUAGE sql IMMUTABLE
3462
    AS $_$
3463
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3464
$_$;
3465

    
3466

    
3467
--
3468
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3469
--
3470

    
3471
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3472
a type''s NOT NULL qualifier
3473
';
3474

    
3475

    
3476
--
3477
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3478
--
3479

    
3480
CREATE FUNCTION typeof(value anyelement) RETURNS text
3481
    LANGUAGE sql IMMUTABLE
3482
    AS $_$
3483
SELECT util.qual_name(pg_typeof($1))
3484
$_$;
3485

    
3486

    
3487
--
3488
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3489
--
3490

    
3491
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3492
    LANGUAGE plpgsql STABLE
3493
    AS $_$
3494
DECLARE
3495
    type regtype;
3496
BEGIN
3497
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3498
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3499
    RETURN type;
3500
END;
3501
$_$;
3502

    
3503

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

    
3508
CREATE AGGREGATE all_same(anyelement) (
3509
    SFUNC = all_same_transform,
3510
    STYPE = anyarray,
3511
    FINALFUNC = all_same_final
3512
);
3513

    
3514

    
3515
--
3516
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3517
--
3518

    
3519
COMMENT ON AGGREGATE all_same(anyelement) IS '
3520
includes NULLs in comparison
3521
';
3522

    
3523

    
3524
--
3525
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3526
--
3527

    
3528
CREATE AGGREGATE join_strs(text, text) (
3529
    SFUNC = join_strs_transform,
3530
    STYPE = text
3531
);
3532

    
3533

    
3534
--
3535
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3536
--
3537

    
3538
CREATE OPERATOR %== (
3539
    PROCEDURE = "%==",
3540
    LEFTARG = anyelement,
3541
    RIGHTARG = anyelement
3542
);
3543

    
3544

    
3545
--
3546
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3547
--
3548

    
3549
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3550
returns whether the map-keys of the compared values are the same
3551
(mnemonic: % is the Perl symbol for a hash map)
3552

    
3553
should be overridden for types that store both keys and values
3554

    
3555
used in a FULL JOIN to select which columns to join on
3556
';
3557

    
3558

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

    
3563
CREATE OPERATOR -> (
3564
    PROCEDURE = map_get,
3565
    LEFTARG = regclass,
3566
    RIGHTARG = text
3567
);
3568

    
3569

    
3570
--
3571
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3572
--
3573

    
3574
CREATE OPERATOR => (
3575
    PROCEDURE = hstore,
3576
    LEFTARG = text[],
3577
    RIGHTARG = text
3578
);
3579

    
3580

    
3581
--
3582
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3583
--
3584

    
3585
COMMENT ON OPERATOR => (text[], text) IS '
3586
usage: array[''key1'', ...]::text[] => ''value''
3587
';
3588

    
3589

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

    
3594
CREATE OPERATOR ?*>= (
3595
    PROCEDURE = is_populated_more_often_than,
3596
    LEFTARG = anyelement,
3597
    RIGHTARG = anyelement
3598
);
3599

    
3600

    
3601
--
3602
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3603
--
3604

    
3605
CREATE OPERATOR ?>= (
3606
    PROCEDURE = is_more_complete_than,
3607
    LEFTARG = anyelement,
3608
    RIGHTARG = anyelement
3609
);
3610

    
3611

    
3612
--
3613
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3614
--
3615

    
3616
CREATE OPERATOR ||% (
3617
    PROCEDURE = concat_esc,
3618
    LEFTARG = text,
3619
    RIGHTARG = text
3620
);
3621

    
3622

    
3623
--
3624
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3625
--
3626

    
3627
COMMENT ON OPERATOR ||% (text, text) IS '
3628
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3629
';
3630

    
3631

    
3632
--
3633
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3634
--
3635

    
3636
CREATE TABLE map (
3637
    "from" text NOT NULL,
3638
    "to" text,
3639
    filter text,
3640
    notes text
3641
);
3642

    
3643

    
3644
--
3645
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3646
--
3647

    
3648

    
3649

    
3650
--
3651
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3652
--
3653

    
3654

    
3655

    
3656
--
3657
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3658
--
3659

    
3660
ALTER TABLE ONLY map
3661
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3662

    
3663

    
3664
--
3665
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3666
--
3667

    
3668
ALTER TABLE ONLY map
3669
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3670

    
3671

    
3672
--
3673
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3674
--
3675

    
3676
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3677

    
3678

    
3679
--
3680
-- PostgreSQL database dump complete
3681
--
3682

    
(19-19/29)