Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

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

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

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

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

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

    
84

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

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

    
93

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

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

    
104

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

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

    
124

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

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

    
133

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

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

    
153

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

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

    
172

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

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

    
190

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

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

    
201

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

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

    
212

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

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

    
225

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

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

    
236

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

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

    
247

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

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

    
258

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

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

    
269

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

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

    
280

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

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

    
291

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

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

    
306

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

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

    
331

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

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

    
342

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

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

    
381

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

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

    
392

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

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

    
431

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

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

    
442

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

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

    
453

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

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

    
464

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

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

    
475

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

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

    
501

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

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

    
521

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

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

    
530

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

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

    
541

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

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

    
552

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

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

    
570

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

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

    
579

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

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

    
590

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

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

    
607

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

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

    
618

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

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

    
629

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

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

    
638

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

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

    
649

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

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

    
660

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

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

    
671

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

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

    
680

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

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

    
691

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

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

    
707

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

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

    
716

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

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

    
732

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

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

    
756

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

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

    
779

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

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

    
790

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

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

    
799

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

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

    
815

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

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

    
832

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

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

    
846

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

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

    
859

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

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

    
882

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

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

    
893

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

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

    
904

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

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

    
915

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

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

    
926

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

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

    
947

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

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

    
956

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

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

    
967

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

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

    
980

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

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

    
997

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

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

    
1013

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

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

    
1022

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

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

    
1035

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

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

    
1046

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

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

    
1083

    
1084
--
1085
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, search_path text, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1086
--
1087

    
1088
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, search_path text, OUT left_ anyelement, OUT right_ anyelement) IS '
1089
col_type_null (*required*): NULL::col_type
1090
single_row: whether the tables consist of a single row, which should be
1091
	displayed side-by-side
1092

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

    
1099

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

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

    
1110

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

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

    
1119

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

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

    
1131

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

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

    
1140

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

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

    
1153

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

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

    
1165

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

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

    
1174

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

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

    
1186

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

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

    
1200

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

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

    
1211

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

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

    
1220

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

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

    
1231

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

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

    
1240

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

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

    
1251

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

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

    
1260

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

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

    
1271

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

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

    
1282

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

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

    
1296

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

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

    
1310

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

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

    
1319

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

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

    
1333

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

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

    
1347

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

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

    
1364

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

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

    
1373

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

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

    
1384

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

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

    
1393

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

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

    
1404

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

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

    
1414

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

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

    
1427

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

    
1432
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1433
    LANGUAGE sql
1434
    AS $_$
1435
SELECT util.eval2set($$EXPLAIN $$||$1)
1436
$_$;
1437

    
1438

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

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

    
1449

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

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

    
1461

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

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

    
1472

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

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

    
1484

    
1485
SET default_tablespace = '';
1486

    
1487
SET default_with_oids = false;
1488

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

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

    
1497

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

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

    
1510

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

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

    
1522

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

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

    
1533

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

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

    
1546

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

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

    
1555

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

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

    
1580

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

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

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

    
1591

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

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

    
1616

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

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

    
1625

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

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

    
1636

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

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

    
1647

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

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

    
1658

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

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

    
1669

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

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

    
1678

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

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

    
1689

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

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

    
1698

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

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

    
1709

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

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

    
1720

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

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

    
1731

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

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

    
1742

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

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

    
1756

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

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

    
1767

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

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

    
1778

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

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

    
1789

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

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

    
1800

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

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

    
1811

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

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

    
1820

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

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

    
1831

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

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

    
1842

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

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

    
1854

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

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

    
1868

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

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

    
1885

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

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

    
1896

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

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

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

    
1913

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

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

    
1926

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

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

    
1940

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

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

    
1949

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

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

    
1960

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

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

    
1969

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

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

    
1987

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

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

    
1996

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

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

    
2016

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

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

    
2025

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

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

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

    
2047

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

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

    
2058

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

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

    
2069

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

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

    
2081

    
2082
--
2083
-- Name: mk_set_search_path(text); Type: FUNCTION; Schema: util; Owner: -
2084
--
2085

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

    
2095

    
2096
--
2097
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2098
--
2099

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

    
2106

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

    
2111
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2112
idempotent
2113
';
2114

    
2115

    
2116
--
2117
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2118
--
2119

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

    
2143

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

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

    
2187

    
2188
--
2189
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2190
--
2191

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

    
2220

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

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

    
2229

    
2230
--
2231
-- Name: mk_use_own_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2232
--
2233

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

    
2240

    
2241
--
2242
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2243
--
2244

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

    
2251

    
2252
--
2253
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2254
--
2255

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

    
2262

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

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

    
2273

    
2274
--
2275
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2276
--
2277

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

    
2284

    
2285
--
2286
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2287
--
2288

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

    
2295

    
2296
--
2297
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2298
--
2299

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

    
2306

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

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

    
2317

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

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

    
2326

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

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

    
2337

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

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

    
2348

    
2349
--
2350
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2351
--
2352

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

    
2360

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

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

    
2372

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

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

    
2381

    
2382
--
2383
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2384
--
2385

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

    
2392

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

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

    
2403

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

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

    
2414

    
2415
--
2416
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2417
--
2418

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

    
2425

    
2426
--
2427
-- Name: raise_error_notice(text); Type: FUNCTION; Schema: util; Owner: -
2428
--
2429

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

    
2436

    
2437
--
2438
-- Name: raise_notice(text); Type: FUNCTION; Schema: util; Owner: -
2439
--
2440

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

    
2449

    
2450
--
2451
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2452
--
2453

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

    
2462

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

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

    
2473

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

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

    
2484

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

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

    
2496

    
2497
--
2498
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2499
--
2500

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

    
2507

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

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

    
2518

    
2519
--
2520
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2521
--
2522

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

    
2529

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

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

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

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

    
2561

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

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

    
2570

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

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

    
2582

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

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

    
2591

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

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

    
2603

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

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

    
2612

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

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

    
2626

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

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

    
2635

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

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

    
2648

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

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

    
2662

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

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

    
2671

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

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

    
2682

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

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

    
2691

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

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

    
2704

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

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

    
2714

    
2715
--
2716
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2717
--
2718

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

    
2726

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

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

    
2737

    
2738
--
2739
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2740
--
2741

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

    
2758

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

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

    
2769

    
2770
--
2771
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
2772
--
2773

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

    
2780

    
2781
--
2782
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2783
--
2784

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

    
2791

    
2792
--
2793
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2794
--
2795

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

    
2802

    
2803
--
2804
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2805
--
2806

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

    
2813

    
2814
--
2815
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2816
--
2817

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

    
2824

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

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

    
2833

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

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

    
2847

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

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

    
2864

    
2865
--
2866
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2867
--
2868

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

    
2877

    
2878
--
2879
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2880
--
2881

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

    
2888

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

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

    
2899

    
2900
--
2901
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
2902
--
2903

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

    
2910

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

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

    
2921

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

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

    
2938

    
2939
--
2940
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2941
--
2942

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

    
2949

    
2950
--
2951
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2952
--
2953

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

    
2961

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

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

    
2982

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

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

    
2991

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

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

    
3023

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

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

    
3033

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

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

    
3064

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

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

    
3073

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

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

    
3084

    
3085
--
3086
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3087
--
3088

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

    
3096

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

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

    
3114

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

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

    
3128

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

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

    
3139

    
3140
--
3141
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3142
--
3143

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

    
3150

    
3151
--
3152
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3153
--
3154

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

    
3167

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

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

    
3179

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

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

    
3188

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

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

    
3200

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

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

    
3210

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

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

    
3221

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

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

    
3230

    
3231
--
3232
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3233
--
3234

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

    
3241

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

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

    
3251

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

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

    
3272

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

    
3277
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3278
idempotent
3279
';
3280

    
3281

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

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

    
3293

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

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

    
3303

    
3304
--
3305
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3306
--
3307

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

    
3316

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

    
3321
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3322
idempotent
3323
';
3324

    
3325

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

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

    
3337

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

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

    
3354

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

    
3359
COMMENT ON FUNCTION try_create(sql text) IS '
3360
idempotent
3361
';
3362

    
3363

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

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

    
3374

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

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

    
3383

    
3384
--
3385
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3386
--
3387

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

    
3394

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

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

    
3403

    
3404
--
3405
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3406
--
3407

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

    
3414

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

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

    
3431

    
3432
--
3433
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3434
--
3435

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

    
3442

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

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

    
3451

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

    
3456
CREATE AGGREGATE join_strs(text, text) (
3457
    SFUNC = join_strs_transform,
3458
    STYPE = text
3459
);
3460

    
3461

    
3462
--
3463
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3464
--
3465

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

    
3472

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

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

    
3481
should be overridden for types that store both keys and values
3482

    
3483
used in a FULL JOIN to select which columns to join on
3484
';
3485

    
3486

    
3487
--
3488
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3489
--
3490

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

    
3497

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

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

    
3508

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

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

    
3517

    
3518
--
3519
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3520
--
3521

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

    
3528

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

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

    
3539

    
3540
--
3541
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3542
--
3543

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

    
3550

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

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

    
3559

    
3560
--
3561
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3562
--
3563

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

    
3571

    
3572
--
3573
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3574
--
3575

    
3576

    
3577

    
3578
--
3579
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3580
--
3581

    
3582

    
3583

    
3584
--
3585
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3586
--
3587

    
3588
ALTER TABLE ONLY map
3589
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3590

    
3591

    
3592
--
3593
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3594
--
3595

    
3596
ALTER TABLE ONLY map
3597
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3598

    
3599

    
3600
--
3601
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3602
--
3603

    
3604
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3605

    
3606

    
3607
--
3608
-- PostgreSQL database dump complete
3609
--
3610

    
(19-19/29)