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: auto_rm_freq(regclass, text); Type: FUNCTION; Schema: util; Owner: -
683
--
684

    
685
CREATE FUNCTION auto_rm_freq(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS void
686
    LANGUAGE sql
687
    AS $_$
688
SELECT CASE WHEN util.freq_always_1($1, $2) THEN util.drop_column(($1, $2)) END
689
$_$;
690

    
691

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

    
696
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
697
    LANGUAGE sql STABLE
698
    AS $_$
699
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
700
$_$;
701

    
702

    
703
--
704
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
705
--
706

    
707
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
708
    LANGUAGE plpgsql STRICT
709
    AS $_$
710
BEGIN
711
    -- not yet clustered (ARRAY[] compares NULLs literally)
712
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
713
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
714
    END IF;
715
END;
716
$_$;
717

    
718

    
719
--
720
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
721
--
722

    
723
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
724
idempotent
725
';
726

    
727

    
728
--
729
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
730
--
731

    
732
CREATE FUNCTION col__min(col col_ref) RETURNS integer
733
    LANGUAGE sql STABLE
734
    AS $_$
735
SELECT util.eval2val($$
736
SELECT $$||quote_ident($1.name)||$$
737
FROM $$||$1.table_||$$
738
ORDER BY $$||quote_ident($1.name)||$$ ASC
739
LIMIT 1
740
$$, NULL::integer)
741
$_$;
742

    
743

    
744
--
745
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
746
--
747

    
748
CREATE FUNCTION col_comment(col col_ref) RETURNS text
749
    LANGUAGE plpgsql STABLE STRICT
750
    AS $$
751
DECLARE
752
	comment text;
753
BEGIN
754
	SELECT description
755
	FROM pg_attribute
756
	LEFT JOIN pg_description ON objoid = attrelid
757
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
758
	WHERE attrelid = col.table_ AND attname = col.name
759
	INTO STRICT comment
760
	;
761
	RETURN comment;
762
EXCEPTION
763
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
764
END;
765
$$;
766

    
767

    
768
--
769
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
770
--
771

    
772
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
773
    LANGUAGE plpgsql STABLE STRICT
774
    AS $$
775
DECLARE
776
	default_sql text;
777
BEGIN
778
	SELECT adsrc
779
	FROM pg_attribute
780
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
781
	WHERE attrelid = col.table_ AND attname = col.name
782
	INTO STRICT default_sql
783
	;
784
	RETURN default_sql;
785
EXCEPTION
786
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
787
END;
788
$$;
789

    
790

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

    
795
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
796
    LANGUAGE sql STABLE
797
    AS $_$
798
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
799
$_$;
800

    
801

    
802
--
803
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
804
--
805

    
806
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
807
ret_type_null: NULL::ret_type
808
';
809

    
810

    
811
--
812
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
813
--
814

    
815
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
816
    LANGUAGE plpgsql STRICT
817
    AS $$
818
BEGIN
819
    PERFORM util.col_type(col);
820
    RETURN true;
821
EXCEPTION
822
    WHEN undefined_column THEN RETURN false;
823
END;
824
$$;
825

    
826

    
827
--
828
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
829
--
830

    
831
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
832
    LANGUAGE plpgsql STABLE STRICT
833
    AS $$
834
DECLARE
835
    prefix text := util.name(type)||'.';
836
BEGIN
837
    RETURN QUERY
838
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
839
        FROM util.col_names(type) f (name_);
840
END;
841
$$;
842

    
843

    
844
--
845
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
846
--
847

    
848
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
849
    LANGUAGE sql STABLE
850
    AS $_$
851
SELECT attname::text
852
FROM pg_attribute
853
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
854
ORDER BY attnum
855
$_$;
856

    
857

    
858
--
859
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
860
--
861

    
862
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
863
    LANGUAGE plpgsql STABLE STRICT
864
    AS $_$
865
BEGIN
866
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
867
END;
868
$_$;
869

    
870

    
871
--
872
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
873
--
874

    
875
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
876
    LANGUAGE plpgsql STABLE STRICT
877
    AS $$
878
DECLARE
879
    type regtype;
880
BEGIN
881
    SELECT atttypid FROM pg_attribute
882
    WHERE attrelid = col.table_ AND attname = col.name
883
    INTO STRICT type
884
    ;
885
    RETURN type;
886
EXCEPTION
887
    WHEN no_data_found THEN
888
        RAISE undefined_column USING MESSAGE =
889
            concat('undefined column: ', col.name);
890
END;
891
$$;
892

    
893

    
894
--
895
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
896
--
897

    
898
CREATE FUNCTION comment(element oid) RETURNS text
899
    LANGUAGE sql STABLE
900
    AS $_$
901
SELECT description FROM pg_description WHERE objoid = $1
902
$_$;
903

    
904

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

    
909
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
910
    LANGUAGE sql IMMUTABLE
911
    AS $_$
912
SELECT util.esc_name__append($2, $1)
913
$_$;
914

    
915

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

    
920
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
921
    LANGUAGE sql IMMUTABLE
922
    AS $_$
923
SELECT position($1 in $2) > 0 /*1-based offset*/
924
$_$;
925

    
926

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

    
931
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
932
    LANGUAGE sql
933
    AS $_$
934
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
935
$_$;
936

    
937

    
938
--
939
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
940
--
941

    
942
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
943
    LANGUAGE sql
944
    AS $_$
945
SELECT util.materialize_view($2, $1)
946
$_$;
947

    
948

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

    
953
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
954
    LANGUAGE plpgsql STRICT
955
    AS $$
956
BEGIN
957
	PERFORM util.eval(sql);
958
EXCEPTION
959
WHEN duplicate_table THEN NULL;
960
WHEN duplicate_object THEN NULL; -- e.g. constraint
961
WHEN duplicate_column THEN NULL;
962
WHEN duplicate_function THEN NULL;
963
WHEN invalid_table_definition THEN
964
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
965
	ELSE RAISE;
966
	END IF;
967
END;
968
$$;
969

    
970

    
971
--
972
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
973
--
974

    
975
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
976
idempotent
977
';
978

    
979

    
980
--
981
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
982
--
983

    
984
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
985
    LANGUAGE sql STABLE
986
    AS $$
987
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
988
$$;
989

    
990

    
991
--
992
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
993
--
994

    
995
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
996
    LANGUAGE sql IMMUTABLE
997
    AS $_$
998
SELECT util.raise('NOTICE', 'returns: '
999
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
1000
SELECT $1;
1001
$_$;
1002

    
1003

    
1004
--
1005
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1006
--
1007

    
1008
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1009
    LANGUAGE sql IMMUTABLE
1010
    AS $_$
1011
/* newline before so the query starts at the beginning of the line.
1012
newline after to visually separate queries from one another. */
1013
SELECT util.raise('NOTICE', $$
1014
$$||util.runnable_sql($1)||$$
1015
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1016
$_$;
1017

    
1018

    
1019
--
1020
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1021
--
1022

    
1023
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1024
    LANGUAGE sql STABLE
1025
    AS $_$
1026
SELECT util.eval2set($$
1027
SELECT col
1028
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1029
LEFT JOIN $$||$2||$$ ON "to" = col
1030
WHERE "from" IS NULL
1031
$$, NULL::text)
1032
$_$;
1033

    
1034

    
1035
--
1036
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1037
--
1038

    
1039
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1040
gets table_''s derived columns (all the columns not in the names table)
1041
';
1042

    
1043

    
1044
--
1045
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1046
--
1047

    
1048
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1049
    LANGUAGE sql
1050
    AS $_$
1051
-- create a diff when the # of copies of a row differs between the tables
1052
SELECT util.to_freq($1);
1053
SELECT util.to_freq($2);
1054
SELECT util.eval($$ALTER TABLE $$||util.typeof($3)||$$ ADD COLUMN copies bigint NOT NULL$$);
1055

    
1056
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1057
$_$;
1058

    
1059

    
1060
--
1061
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1062
--
1063

    
1064
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1065
usage:
1066
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1067

    
1068
col_type_null (*required*): NULL::shared_base_type
1069
';
1070

    
1071

    
1072
--
1073
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1074
--
1075

    
1076
CREATE FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1077
    LANGUAGE plpgsql
1078
    SET search_path TO pg_temp
1079
    AS $_$
1080
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1081
changes of search_path (schema elements are bound at inline time rather than
1082
runtime) */
1083
/* function option search_path is needed to limit the effects of
1084
`SET LOCAL search_path` to the current function */
1085
BEGIN
1086
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1087
	
1088
	PERFORM util.mk_keys_func(pg_typeof($3));
1089
	RETURN QUERY
1090
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1091
$$/* need to explicitly cast each side to the return type because this does not
1092
happen automatically even when an implicit cast is available */
1093
  left_::$$||util.typeof($3)||$$
1094
, right_::$$||util.typeof($3)
1095
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1096
the *same* base type, *even though* this is optional when using a custom %== */
1097
, util._if($4, $$true/*= CROSS JOIN*/$$,
1098
$$ left_::$$||util.typeof($3)||$$
1099
%== right_::$$||util.typeof($3)||$$
1100
	-- refer to EXPLAIN output for expansion of %==$$
1101
)
1102
,     $$         left_::$$||util.typeof($3)||$$
1103
IS DISTINCT FROM right_::$$||util.typeof($3)
1104
), $3)
1105
	;
1106
END;
1107
$_$;
1108

    
1109

    
1110
--
1111
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1112
--
1113

    
1114
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1115
col_type_null (*required*): NULL::col_type
1116
single_row: whether the tables consist of a single row, which should be
1117
	displayed side-by-side
1118

    
1119
to match up rows using a subset of the columns, create a custom keys() function
1120
which returns this subset as a record:
1121
-- note that OUT parameters for the returned fields are *not* needed
1122
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1123
  RETURNS record AS
1124
$BODY$
1125
SELECT ($1.key_field_0, $1.key_field_1)
1126
$BODY$
1127
  LANGUAGE sql IMMUTABLE
1128
  COST 100;
1129

    
1130

    
1131
to run EXPLAIN on the FULL JOIN query:
1132
# run this function
1133
# look for a NOTICE containing the expanded query that it ran
1134
# run EXPLAIN on this expanded query
1135
';
1136

    
1137

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

    
1142
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1143
    LANGUAGE sql
1144
    AS $_$
1145
SELECT * FROM util.diff($1::text, $2::text, $3,
1146
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1147
$_$;
1148

    
1149

    
1150
--
1151
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1152
--
1153

    
1154
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1155
helper function used by diff(regclass, regclass)
1156

    
1157
usage:
1158
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1159

    
1160
col_type_null (*required*): NULL::shared_base_type
1161
';
1162

    
1163

    
1164
--
1165
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1166
--
1167

    
1168
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1169
    LANGUAGE sql
1170
    AS $_$
1171
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1172
$_$;
1173

    
1174

    
1175
--
1176
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1177
--
1178

    
1179
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1180
idempotent
1181
';
1182

    
1183

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

    
1188
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1189
    LANGUAGE sql
1190
    AS $_$
1191
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1192
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1193
$_$;
1194

    
1195

    
1196
--
1197
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1198
--
1199

    
1200
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1201
idempotent
1202
';
1203

    
1204

    
1205
--
1206
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1207
--
1208

    
1209
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1210
    LANGUAGE sql
1211
    AS $_$
1212
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1213
included in the debug SQL */
1214
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1215
$_$;
1216

    
1217

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

    
1222
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1223
    LANGUAGE sql
1224
    AS $_$
1225
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1226
||util._if($3, $$ CASCADE$$, ''::text))
1227
$_$;
1228

    
1229

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

    
1234
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1235
idempotent
1236
';
1237

    
1238

    
1239
--
1240
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1241
--
1242

    
1243
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1244
    LANGUAGE sql
1245
    AS $_$
1246
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1247
$_$;
1248

    
1249

    
1250
--
1251
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1252
--
1253

    
1254
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1255
    LANGUAGE sql
1256
    AS $_$
1257
SELECT util.drop_relation(relation, $3)
1258
FROM util.show_relations_like($1, $2) relation
1259
;
1260
SELECT NULL::void; -- don't fold away functions called in previous query
1261
$_$;
1262

    
1263

    
1264
--
1265
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1266
--
1267

    
1268
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1269
    LANGUAGE sql
1270
    AS $_$
1271
SELECT util.drop_relation('TABLE', $1, $2)
1272
$_$;
1273

    
1274

    
1275
--
1276
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1277
--
1278

    
1279
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1280
idempotent
1281
';
1282

    
1283

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

    
1288
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1289
    LANGUAGE sql
1290
    AS $_$
1291
SELECT util.drop_relation('VIEW', $1, $2)
1292
$_$;
1293

    
1294

    
1295
--
1296
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1297
--
1298

    
1299
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1300
idempotent
1301
';
1302

    
1303

    
1304
--
1305
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1306
--
1307

    
1308
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1309
    LANGUAGE sql IMMUTABLE
1310
    AS $_$
1311
SELECT util.array_fill($1, 0)
1312
$_$;
1313

    
1314

    
1315
--
1316
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1317
--
1318

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

    
1323

    
1324
--
1325
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1326
--
1327

    
1328
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1329
    LANGUAGE sql IMMUTABLE
1330
    AS $_$
1331
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1332
$_$;
1333

    
1334

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

    
1339
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1340
    LANGUAGE sql IMMUTABLE
1341
    AS $_$
1342
SELECT regexp_replace($2, '("?)$', $1||'\1')
1343
$_$;
1344

    
1345

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

    
1350
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1351
    LANGUAGE plpgsql
1352
    AS $$
1353
BEGIN
1354
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1355
	EXECUTE sql;
1356
END;
1357
$$;
1358

    
1359

    
1360
--
1361
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1362
--
1363

    
1364
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1365
    LANGUAGE plpgsql
1366
    AS $$
1367
BEGIN
1368
	PERFORM util.debug_print_sql(sql);
1369
	RETURN QUERY EXECUTE sql;
1370
END;
1371
$$;
1372

    
1373

    
1374
--
1375
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1376
--
1377

    
1378
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1379
col_type_null (*required*): NULL::col_type
1380
';
1381

    
1382

    
1383
--
1384
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1385
--
1386

    
1387
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1388
    LANGUAGE plpgsql
1389
    AS $$
1390
BEGIN
1391
	PERFORM util.debug_print_sql(sql);
1392
	RETURN QUERY EXECUTE sql;
1393
END;
1394
$$;
1395

    
1396

    
1397
--
1398
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1399
--
1400

    
1401
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1402
    LANGUAGE plpgsql
1403
    AS $$
1404
BEGIN
1405
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1406
	RETURN QUERY EXECUTE sql;
1407
END;
1408
$$;
1409

    
1410

    
1411
--
1412
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1413
--
1414

    
1415
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1416
    LANGUAGE plpgsql STABLE
1417
    AS $$
1418
DECLARE
1419
	ret_val ret_type_null%TYPE;
1420
BEGIN
1421
	PERFORM util.debug_print_sql(sql);
1422
	EXECUTE sql INTO STRICT ret_val;
1423
	RETURN ret_val;
1424
END;
1425
$$;
1426

    
1427

    
1428
--
1429
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1430
--
1431

    
1432
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1433
ret_type_null: NULL::ret_type
1434
';
1435

    
1436

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

    
1441
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1442
    LANGUAGE sql
1443
    AS $_$
1444
SELECT util.eval2val($$SELECT $$||$1, $2)
1445
$_$;
1446

    
1447

    
1448
--
1449
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1450
--
1451

    
1452
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1453
ret_type_null: NULL::ret_type
1454
';
1455

    
1456

    
1457
--
1458
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1459
--
1460

    
1461
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1462
    LANGUAGE sql
1463
    AS $_$
1464
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1465
$_$;
1466

    
1467

    
1468
--
1469
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1470
--
1471

    
1472
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1473
sql: can be NULL, which will be passed through
1474
ret_type_null: NULL::ret_type
1475
';
1476

    
1477

    
1478
--
1479
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1480
--
1481

    
1482
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1483
    LANGUAGE sql STABLE
1484
    AS $_$
1485
SELECT col_name
1486
FROM unnest($2) s (col_name)
1487
WHERE util.col_exists(($1, col_name))
1488
$_$;
1489

    
1490

    
1491
--
1492
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1493
--
1494

    
1495
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1496
    LANGUAGE sql
1497
    AS $_$
1498
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1499
$_$;
1500

    
1501

    
1502
--
1503
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1504
--
1505

    
1506
CREATE FUNCTION explain2notice(sql text) RETURNS void
1507
    LANGUAGE sql
1508
    AS $_$
1509
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1510
$_$;
1511

    
1512

    
1513
--
1514
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1515
--
1516

    
1517
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1518
    LANGUAGE sql
1519
    AS $_$
1520
-- newline before and after to visually separate it from other debug info
1521
SELECT $$
1522
EXPLAIN:
1523
$$||util.explain2str($1)||$$
1524
$$
1525
$_$;
1526

    
1527

    
1528
--
1529
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1530
--
1531

    
1532
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1533
    LANGUAGE sql
1534
    AS $_$
1535
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1536
$_$;
1537

    
1538

    
1539
--
1540
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1541
--
1542

    
1543
CREATE FUNCTION explain2str(sql text) RETURNS text
1544
    LANGUAGE sql
1545
    AS $_$
1546
SELECT util.join_strs(explain, $$
1547
$$) FROM util.explain($1)
1548
$_$;
1549

    
1550

    
1551
SET default_tablespace = '';
1552

    
1553
SET default_with_oids = false;
1554

    
1555
--
1556
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1557
--
1558

    
1559
CREATE TABLE explain (
1560
    line text NOT NULL
1561
);
1562

    
1563

    
1564
--
1565
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1566
--
1567

    
1568
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1569
    LANGUAGE sql
1570
    AS $_$
1571
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1572
$$||quote_nullable($1)||$$
1573
)$$)
1574
$_$;
1575

    
1576

    
1577
--
1578
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1579
--
1580

    
1581
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1582
usage:
1583
PERFORM util.explain2table($$
1584
query
1585
$$);
1586
';
1587

    
1588

    
1589
--
1590
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1591
--
1592

    
1593
CREATE FUNCTION first_word(str text) RETURNS text
1594
    LANGUAGE sql IMMUTABLE
1595
    AS $_$
1596
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1597
$_$;
1598

    
1599

    
1600
--
1601
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1602
--
1603

    
1604
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1605
    LANGUAGE sql IMMUTABLE
1606
    AS $_$
1607
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1608
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1609
) END
1610
$_$;
1611

    
1612

    
1613
--
1614
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1615
--
1616

    
1617
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1618
ensures that an array will always have proper non-NULL dimensions
1619
';
1620

    
1621

    
1622
--
1623
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1624
--
1625

    
1626
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1627
    LANGUAGE plpgsql
1628
    AS $_$
1629
DECLARE
1630
	PG_EXCEPTION_DETAIL text;
1631
	recreate_users_cmd text = util.save_drop_views(users);
1632
BEGIN
1633
	PERFORM util.eval(cmd);
1634
	PERFORM util.eval(recreate_users_cmd);
1635
EXCEPTION
1636
WHEN dependent_objects_still_exist THEN
1637
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1638
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1639
	users = array(SELECT * FROM util.regexp_matches_group(
1640
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1641
	IF util.is_empty(users) THEN RAISE; END IF;
1642
	PERFORM util.force_recreate(cmd, users);
1643
END;
1644
$_$;
1645

    
1646

    
1647
--
1648
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1649
--
1650

    
1651
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1652
idempotent
1653

    
1654
users: not necessary to provide this because it will be autopopulated
1655
';
1656

    
1657

    
1658
--
1659
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1660
--
1661

    
1662
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1663
    LANGUAGE plpgsql STRICT
1664
    AS $_$
1665
DECLARE
1666
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1667
$$||query;
1668
BEGIN
1669
	EXECUTE mk_view;
1670
EXCEPTION
1671
WHEN invalid_table_definition THEN
1672
	IF SQLERRM = 'cannot drop columns from view'
1673
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1674
	THEN
1675
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1676
		EXECUTE mk_view;
1677
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1678
	END IF;
1679
END;
1680
$_$;
1681

    
1682

    
1683
--
1684
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1685
--
1686

    
1687
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1688
idempotent
1689
';
1690

    
1691

    
1692
--
1693
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1694
--
1695

    
1696
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1697
    LANGUAGE sql STABLE
1698
    AS $_$
1699
SELECT util.eval2val(
1700
$$SELECT NOT EXISTS( -- there is no row that is != 1
1701
	SELECT NULL
1702
	FROM $$||$1||$$
1703
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1704
	LIMIT 1
1705
)
1706
$$, NULL::boolean)
1707
$_$;
1708

    
1709

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

    
1714
CREATE FUNCTION grants_users() RETURNS SETOF text
1715
    LANGUAGE sql IMMUTABLE
1716
    AS $$
1717
VALUES ('bien_read'), ('public_')
1718
$$;
1719

    
1720

    
1721
--
1722
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1723
--
1724

    
1725
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1726
    LANGUAGE sql IMMUTABLE
1727
    AS $_$
1728
SELECT substring($2 for length($1)) = $1
1729
$_$;
1730

    
1731

    
1732
--
1733
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1734
--
1735

    
1736
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1737
    LANGUAGE sql STABLE
1738
    AS $_$
1739
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1740
$_$;
1741

    
1742

    
1743
--
1744
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1745
--
1746

    
1747
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1748
    LANGUAGE sql IMMUTABLE
1749
    AS $_$
1750
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1751
$_$;
1752

    
1753

    
1754
--
1755
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1756
--
1757

    
1758
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1759
avoids repeating the same value for each key
1760
';
1761

    
1762

    
1763
--
1764
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1765
--
1766

    
1767
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1768
    LANGUAGE sql IMMUTABLE
1769
    AS $_$
1770
SELECT COALESCE($1, $2)
1771
$_$;
1772

    
1773

    
1774
--
1775
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1776
--
1777

    
1778
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1779
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1780
';
1781

    
1782

    
1783
--
1784
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1785
--
1786

    
1787
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1788
    LANGUAGE sql
1789
    AS $_$
1790
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1791
$_$;
1792

    
1793

    
1794
--
1795
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1796
--
1797

    
1798
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1799
    LANGUAGE sql STABLE
1800
    AS $_$
1801
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1802
$_$;
1803

    
1804

    
1805
--
1806
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1807
--
1808

    
1809
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1810
    LANGUAGE sql IMMUTABLE
1811
    AS $_$
1812
SELECT util.array_length($1) = 0
1813
$_$;
1814

    
1815

    
1816
--
1817
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1818
--
1819

    
1820
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1821
    LANGUAGE sql IMMUTABLE
1822
    AS $_$
1823
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1824
$_$;
1825

    
1826

    
1827
--
1828
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1829
--
1830

    
1831
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1832
    LANGUAGE sql IMMUTABLE
1833
    AS $_$
1834
SELECT upper(util.first_word($1)) = ANY(
1835
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1836
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1837
)
1838
$_$;
1839

    
1840

    
1841
--
1842
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1843
--
1844

    
1845
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1846
    LANGUAGE sql IMMUTABLE
1847
    AS $_$
1848
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1849
$_$;
1850

    
1851

    
1852
--
1853
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1854
--
1855

    
1856
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1857
    LANGUAGE sql IMMUTABLE
1858
    AS $_$
1859
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1860
$_$;
1861

    
1862

    
1863
--
1864
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1865
--
1866

    
1867
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1868
    LANGUAGE sql IMMUTABLE
1869
    AS $_$
1870
SELECT upper(util.first_word($1)) = 'SET'
1871
$_$;
1872

    
1873

    
1874
--
1875
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1876
--
1877

    
1878
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1879
    LANGUAGE sql STABLE
1880
    AS $_$
1881
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1882
$_$;
1883

    
1884

    
1885
--
1886
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1887
--
1888

    
1889
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1890
    LANGUAGE sql STABLE
1891
    AS $_$
1892
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1893
$_$;
1894

    
1895

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

    
1900
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1901
    LANGUAGE sql IMMUTABLE STRICT
1902
    AS $_$
1903
SELECT $1 || $3 || $2
1904
$_$;
1905

    
1906

    
1907
--
1908
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1909
--
1910

    
1911
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1912
must be declared STRICT to use the special handling of STRICT aggregating functions
1913
';
1914

    
1915

    
1916
--
1917
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1918
--
1919

    
1920
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1921
    LANGUAGE sql IMMUTABLE
1922
    AS $_$
1923
SELECT $1 -- compare on the entire value
1924
$_$;
1925

    
1926

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

    
1931
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1932
    LANGUAGE sql IMMUTABLE
1933
    AS $_$
1934
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1935
$_$;
1936

    
1937

    
1938
--
1939
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1940
--
1941

    
1942
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1943
    LANGUAGE sql IMMUTABLE
1944
    AS $_$
1945
SELECT ltrim($1, $$
1946
$$)
1947
$_$;
1948

    
1949

    
1950
--
1951
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1952
--
1953

    
1954
CREATE FUNCTION map_filter_insert() RETURNS trigger
1955
    LANGUAGE plpgsql
1956
    AS $$
1957
BEGIN
1958
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1959
	RETURN new;
1960
END;
1961
$$;
1962

    
1963

    
1964
--
1965
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1966
--
1967

    
1968
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1969
    LANGUAGE plpgsql STABLE STRICT
1970
    AS $_$
1971
DECLARE
1972
    value text;
1973
BEGIN
1974
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1975
        INTO value USING key;
1976
    RETURN value;
1977
END;
1978
$_$;
1979

    
1980

    
1981
--
1982
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1983
--
1984

    
1985
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1986
    LANGUAGE sql IMMUTABLE
1987
    AS $_$
1988
SELECT util._map(util.nulls_map($1), $2)
1989
$_$;
1990

    
1991

    
1992
--
1993
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1994
--
1995

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

    
1999
[1] inlining of function calls, which is different from constant folding
2000
[2] _map()''s profiling query
2001
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2002
and map_nulls()''s profiling query
2003
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2004
both take ~920 ms.
2005
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.
2006
';
2007

    
2008

    
2009
--
2010
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2011
--
2012

    
2013
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2014
    LANGUAGE plpgsql STABLE STRICT
2015
    AS $_$
2016
BEGIN
2017
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2018
END;
2019
$_$;
2020

    
2021

    
2022
--
2023
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2024
--
2025

    
2026
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2027
    LANGUAGE sql
2028
    AS $_$
2029
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2030
$$||util.ltrim_nl($2));
2031
-- make sure the created table has the correct estimated row count
2032
SELECT util.analyze_($1);
2033

    
2034
SELECT util.append_comment($1, '
2035
contents generated from:
2036
'||util.ltrim_nl($2)||';
2037
');
2038
$_$;
2039

    
2040

    
2041
--
2042
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2043
--
2044

    
2045
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2046
idempotent
2047
';
2048

    
2049

    
2050
--
2051
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2052
--
2053

    
2054
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2055
    LANGUAGE sql
2056
    AS $_$
2057
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2058
$_$;
2059

    
2060

    
2061
--
2062
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2063
--
2064

    
2065
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2066
idempotent
2067
';
2068

    
2069

    
2070
--
2071
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2072
--
2073

    
2074
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2075
    LANGUAGE sql
2076
    AS $_$
2077
SELECT util.create_if_not_exists($$
2078
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2079
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2080
||quote_literal($2)||$$;
2081
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2082
constant
2083
';
2084
$$)
2085
$_$;
2086

    
2087

    
2088
--
2089
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2090
--
2091

    
2092
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2093
idempotent
2094
';
2095

    
2096

    
2097
--
2098
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2099
--
2100

    
2101
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2102
    LANGUAGE plpgsql STRICT
2103
    AS $_$
2104
DECLARE
2105
    type regtype = util.typeof(expr, col.table_::text::regtype);
2106
    col_name_sql text = quote_ident(col.name);
2107
BEGIN
2108
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2109
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2110
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2111
$$||expr||$$;
2112
$$);
2113
END;
2114
$_$;
2115

    
2116

    
2117
--
2118
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2119
--
2120

    
2121
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2122
idempotent
2123
';
2124

    
2125

    
2126
--
2127
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2128
--
2129

    
2130
CREATE FUNCTION mk_diff_query(left_ text, right_ text, cols text DEFAULT 'left_, right_'::text, join_cond text DEFAULT 'left_ %== right_ -- refer to EXPLAIN output for expansion of %=='::text, filter text DEFAULT 'left_ IS DISTINCT FROM right_'::text) RETURNS text
2131
    LANGUAGE sql IMMUTABLE
2132
    AS $_$
2133
SELECT
2134
$$SELECT
2135
$$||$3||$$
2136
FROM      $$||$1||$$ left_
2137
FULL JOIN $$||$2||$$ right_
2138
ON $$||$4||$$
2139
WHERE $$||$5||$$
2140
ORDER BY left_, right_
2141
$$
2142
$_$;
2143

    
2144

    
2145
--
2146
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2147
--
2148

    
2149
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2150
    LANGUAGE sql
2151
    AS $_$
2152
-- keys()
2153
SELECT util.mk_keys_func($1, ARRAY(
2154
SELECT col FROM util.typed_cols($1) col
2155
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2156
));
2157

    
2158
-- values_()
2159
SELECT util.mk_keys_func($1, COALESCE(
2160
	NULLIF(ARRAY(
2161
	SELECT col FROM util.typed_cols($1) col
2162
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2163
	), ARRAY[]::util.col_cast[])
2164
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2165
, 'values_');
2166
$_$;
2167

    
2168

    
2169
--
2170
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2171
--
2172

    
2173
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2174
    LANGUAGE sql
2175
    AS $_$
2176
SELECT util.create_if_not_exists($$
2177
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2178
($$||util.mk_typed_cols_list($2)||$$);
2179
$$);
2180

    
2181
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2182
$_$;
2183

    
2184

    
2185
--
2186
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2187
--
2188

    
2189
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2190
    LANGUAGE sql
2191
    AS $_$
2192
SELECT util.create_if_not_exists($$
2193
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2194
||util.qual_name($1)||$$)
2195
  RETURNS $$||util.qual_name($2)||$$ AS
2196
$BODY1$
2197
SELECT ROW($$||
2198
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2199
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2200
$BODY1$
2201
  LANGUAGE sql IMMUTABLE
2202
  COST 100;
2203
$$);
2204
$_$;
2205

    
2206

    
2207
--
2208
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2209
--
2210

    
2211
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2212
    LANGUAGE sql
2213
    AS $_$
2214
SELECT util.create_if_not_exists($$
2215
CREATE TABLE $$||$1||$$
2216
(
2217
    LIKE util.map INCLUDING ALL
2218
);
2219

    
2220
CREATE TRIGGER map_filter_insert
2221
  BEFORE INSERT
2222
  ON $$||$1||$$
2223
  FOR EACH ROW
2224
  EXECUTE PROCEDURE util.map_filter_insert();
2225
$$)
2226
$_$;
2227

    
2228

    
2229
--
2230
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2231
--
2232

    
2233
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2234
    LANGUAGE sql IMMUTABLE
2235
    AS $_$
2236
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2237
util.qual_name((unnest).type), ''), '')
2238
FROM unnest($1)
2239
$_$;
2240

    
2241

    
2242
--
2243
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2244
--
2245

    
2246
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2247
    LANGUAGE sql IMMUTABLE
2248
    AS $_$
2249
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2250
$_$;
2251

    
2252

    
2253
--
2254
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2255
--
2256

    
2257
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2258
auto-appends util to the search_path to enable use of util operators
2259
';
2260

    
2261

    
2262
--
2263
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2264
--
2265

    
2266
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2267
    LANGUAGE sql IMMUTABLE
2268
    AS $_$
2269
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2270
$_$;
2271

    
2272

    
2273
--
2274
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2275
--
2276

    
2277
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2278
    LANGUAGE sql IMMUTABLE
2279
    AS $_$
2280
/* debug_print_return_value() needed because this function is used with EXECUTE
2281
rather than util.eval() (in order to affect the calling function), so the
2282
search_path would not otherwise be printed */
2283
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2284
||$$ search_path TO $$||$1
2285
$_$;
2286

    
2287

    
2288
--
2289
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2290
--
2291

    
2292
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2293
    LANGUAGE sql
2294
    AS $_$
2295
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2296
$_$;
2297

    
2298

    
2299
--
2300
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2301
--
2302

    
2303
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2304
idempotent
2305
';
2306

    
2307

    
2308
--
2309
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2310
--
2311

    
2312
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2313
    LANGUAGE plpgsql STRICT
2314
    AS $_$
2315
DECLARE
2316
	view_qual_name text = util.qual_name(view_);
2317
BEGIN
2318
	EXECUTE $$
2319
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2320
  RETURNS SETOF $$||view_||$$ AS
2321
$BODY1$
2322
SELECT * FROM $$||view_qual_name||$$
2323
ORDER BY sort_col
2324
LIMIT $1 OFFSET $2
2325
$BODY1$
2326
  LANGUAGE sql STABLE
2327
  COST 100
2328
  ROWS 1000
2329
$$;
2330
	
2331
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2332
END;
2333
$_$;
2334

    
2335

    
2336
--
2337
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2338
--
2339

    
2340
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2341
    LANGUAGE plpgsql STRICT
2342
    AS $_$
2343
DECLARE
2344
	view_qual_name text = util.qual_name(view_);
2345
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2346
BEGIN
2347
	EXECUTE $$
2348
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2349
  RETURNS integer AS
2350
$BODY1$
2351
SELECT $$||quote_ident(row_num_col)||$$
2352
FROM $$||view_qual_name||$$
2353
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2354
LIMIT 1
2355
$BODY1$
2356
  LANGUAGE sql STABLE
2357
  COST 100;
2358
$$;
2359
	
2360
	EXECUTE $$
2361
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2362
  RETURNS SETOF $$||view_||$$ AS
2363
$BODY1$
2364
SELECT * FROM $$||view_qual_name||$$
2365
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2366
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2367
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2368
ORDER BY $$||quote_ident(row_num_col)||$$
2369
$BODY1$
2370
  LANGUAGE sql STABLE
2371
  COST 100
2372
  ROWS 1000
2373
$$;
2374
	
2375
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2376
END;
2377
$_$;
2378

    
2379

    
2380
--
2381
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2382
--
2383

    
2384
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2385
    LANGUAGE plpgsql STRICT
2386
    AS $_$
2387
DECLARE
2388
	view_qual_name text = util.qual_name(view_);
2389
BEGIN
2390
	EXECUTE $$
2391
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2392
  RETURNS SETOF $$||view_||$$
2393
  SET enable_sort TO 'off'
2394
  AS
2395
$BODY1$
2396
SELECT * FROM $$||view_qual_name||$$($2, $3)
2397
$BODY1$
2398
  LANGUAGE sql STABLE
2399
  COST 100
2400
  ROWS 1000
2401
;
2402
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2403
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2404
If you want to run EXPLAIN and get expanded output, use the regular subset
2405
function instead. (When a config param is set on a function, EXPLAIN produces
2406
just a function scan.)
2407
';
2408
$$;
2409
END;
2410
$_$;
2411

    
2412

    
2413
--
2414
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2415
--
2416

    
2417
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2418
creates subset function which turns off enable_sort
2419
';
2420

    
2421

    
2422
--
2423
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2424
--
2425

    
2426
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2427
    LANGUAGE sql IMMUTABLE
2428
    AS $_$
2429
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2430
util.qual_name((unnest).type), ', '), '')
2431
FROM unnest($1)
2432
$_$;
2433

    
2434

    
2435
--
2436
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2437
--
2438

    
2439
CREATE FUNCTION name(table_ regclass) RETURNS text
2440
    LANGUAGE sql STABLE
2441
    AS $_$
2442
SELECT relname::text FROM pg_class WHERE oid = $1
2443
$_$;
2444

    
2445

    
2446
--
2447
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2448
--
2449

    
2450
CREATE FUNCTION name(type regtype) RETURNS text
2451
    LANGUAGE sql STABLE
2452
    AS $_$
2453
SELECT typname::text FROM pg_type WHERE oid = $1
2454
$_$;
2455

    
2456

    
2457
--
2458
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2459
--
2460

    
2461
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2462
    LANGUAGE sql IMMUTABLE
2463
    AS $_$
2464
SELECT octet_length($1) >= util.namedatalen() - $2
2465
$_$;
2466

    
2467

    
2468
--
2469
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2470
--
2471

    
2472
CREATE FUNCTION namedatalen() RETURNS integer
2473
    LANGUAGE sql IMMUTABLE
2474
    AS $$
2475
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2476
$$;
2477

    
2478

    
2479
--
2480
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2481
--
2482

    
2483
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2484
    LANGUAGE sql IMMUTABLE
2485
    AS $_$
2486
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2487
$_$;
2488

    
2489

    
2490
--
2491
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2492
--
2493

    
2494
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2495
    LANGUAGE sql IMMUTABLE
2496
    AS $_$
2497
SELECT $1 IS NOT NULL
2498
$_$;
2499

    
2500

    
2501
--
2502
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2503
--
2504

    
2505
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2506
    LANGUAGE sql IMMUTABLE
2507
    AS $_$
2508
SELECT util.hstore($1, NULL) || '*=>*'
2509
$_$;
2510

    
2511

    
2512
--
2513
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2514
--
2515

    
2516
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2517
for use with _map()
2518
';
2519

    
2520

    
2521
--
2522
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2523
--
2524

    
2525
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2526
    LANGUAGE sql IMMUTABLE
2527
    AS $_$
2528
SELECT $2 + COALESCE($1, 0)
2529
$_$;
2530

    
2531

    
2532
--
2533
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2534
--
2535

    
2536
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2537
    LANGUAGE sql
2538
    AS $_$
2539
SELECT util.eval($$INSERT INTO $$||$1||$$
2540
$$||util.ltrim_nl($2));
2541
-- make sure the created table has the correct estimated row count
2542
SELECT util.analyze_($1);
2543
$_$;
2544

    
2545

    
2546
--
2547
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2548
--
2549

    
2550
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2551
    LANGUAGE sql IMMUTABLE
2552
    AS $_$
2553
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2554
$_$;
2555

    
2556

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

    
2561
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2562
    LANGUAGE sql
2563
    AS $_$
2564
SELECT util.set_comment($1, concat($2, util.comment($1)))
2565
$_$;
2566

    
2567

    
2568
--
2569
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2570
--
2571

    
2572
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2573
comment: must start and end with a newline
2574
';
2575

    
2576

    
2577
--
2578
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2579
--
2580

    
2581
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2582
    LANGUAGE sql IMMUTABLE
2583
    AS $_$
2584
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2585
$_$;
2586

    
2587

    
2588
--
2589
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2590
--
2591

    
2592
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2593
    LANGUAGE sql STABLE
2594
    SET search_path TO pg_temp
2595
    AS $_$
2596
SELECT $1::text
2597
$_$;
2598

    
2599

    
2600
--
2601
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2602
--
2603

    
2604
CREATE FUNCTION qual_name(type regtype) RETURNS text
2605
    LANGUAGE sql STABLE
2606
    SET search_path TO pg_temp
2607
    AS $_$
2608
SELECT $1::text
2609
$_$;
2610

    
2611

    
2612
--
2613
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2614
--
2615

    
2616
COMMENT ON FUNCTION qual_name(type regtype) IS '
2617
a type''s schema-qualified name
2618
';
2619

    
2620

    
2621
--
2622
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2623
--
2624

    
2625
CREATE FUNCTION qual_name(type unknown) RETURNS text
2626
    LANGUAGE sql STABLE
2627
    AS $_$
2628
SELECT util.qual_name($1::text::regtype)
2629
$_$;
2630

    
2631

    
2632
--
2633
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2634
--
2635

    
2636
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2637
    LANGUAGE sql IMMUTABLE
2638
    AS $_$
2639
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2640
$_$;
2641

    
2642

    
2643
--
2644
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2645
--
2646

    
2647
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2648
    LANGUAGE sql IMMUTABLE
2649
    AS $_$
2650
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2651
$_$;
2652

    
2653

    
2654
--
2655
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2656
--
2657

    
2658
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2659
    LANGUAGE sql IMMUTABLE
2660
    AS $_$
2661
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2662
$_$;
2663

    
2664

    
2665
--
2666
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2667
--
2668

    
2669
CREATE FUNCTION raise(type text, msg text) RETURNS void
2670
    LANGUAGE sql IMMUTABLE
2671
    AS $_X$
2672
SELECT util.eval($$
2673
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2674
  RETURNS void AS
2675
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2676
$__BODY1$
2677
BEGIN
2678
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2679
END;
2680
$__BODY1$
2681
  LANGUAGE plpgsql IMMUTABLE
2682
  COST 100;
2683
$$, verbose_ := false);
2684

    
2685
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2686
$_X$;
2687

    
2688

    
2689
--
2690
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2691
--
2692

    
2693
COMMENT ON FUNCTION raise(type text, msg text) IS '
2694
type: a log level from
2695
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2696
or a condition name from
2697
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2698
';
2699

    
2700

    
2701
--
2702
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2703
--
2704

    
2705
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2706
    LANGUAGE sql IMMUTABLE
2707
    AS $_$
2708
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2709
$_$;
2710

    
2711

    
2712
--
2713
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2714
--
2715

    
2716
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2717
    LANGUAGE plpgsql IMMUTABLE STRICT
2718
    AS $$
2719
BEGIN
2720
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2721
END;
2722
$$;
2723

    
2724

    
2725
--
2726
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2727
--
2728

    
2729
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2730
    LANGUAGE sql IMMUTABLE
2731
    AS $_$
2732
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2733
$_$;
2734

    
2735

    
2736
--
2737
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2738
--
2739

    
2740
CREATE FUNCTION regexp_quote(str text) RETURNS text
2741
    LANGUAGE sql IMMUTABLE
2742
    AS $_$
2743
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2744
$_$;
2745

    
2746

    
2747
--
2748
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2749
--
2750

    
2751
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2752
    LANGUAGE sql IMMUTABLE
2753
    AS $_$
2754
SELECT (CASE WHEN right($1, 1) = ')'
2755
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2756
$_$;
2757

    
2758

    
2759
--
2760
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2761
--
2762

    
2763
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2764
    LANGUAGE sql STABLE
2765
    AS $_$
2766
SELECT util.relation_type(util.relation_type_char($1))
2767
$_$;
2768

    
2769

    
2770
--
2771
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2772
--
2773

    
2774
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2775
    LANGUAGE sql IMMUTABLE
2776
    AS $_$
2777
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2778
$_$;
2779

    
2780

    
2781
--
2782
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2783
--
2784

    
2785
CREATE FUNCTION relation_type(type regtype) RETURNS text
2786
    LANGUAGE sql IMMUTABLE
2787
    AS $$
2788
SELECT 'TYPE'::text
2789
$$;
2790

    
2791

    
2792
--
2793
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2794
--
2795

    
2796
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2797
    LANGUAGE sql STABLE
2798
    AS $_$
2799
SELECT relkind FROM pg_class WHERE oid = $1
2800
$_$;
2801

    
2802

    
2803
--
2804
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2805
--
2806

    
2807
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2808
    LANGUAGE sql
2809
    AS $_$
2810
/* can't have in_table/out_table inherit from *each other*, because inheritance
2811
also causes the rows of the parent table to be included in the child table.
2812
instead, they need to inherit from a common, empty table. */
2813
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2814
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2815
SELECT util.inherit($2, $4);
2816
SELECT util.inherit($3, $4);
2817

    
2818
SELECT util.rematerialize_query($1, $$
2819
SELECT * FROM util.diff(
2820
  $$||util.quote_typed($2)||$$
2821
, $$||util.quote_typed($3)||$$
2822
, NULL::$$||$4||$$)
2823
$$);
2824

    
2825
/* the table unfortunately cannot be *materialized* in human-readable form,
2826
because this would create column name collisions between the two sides */
2827
SELECT util.prepend_comment($1, '
2828
to view this table in human-readable form (with each side''s tuple column
2829
expanded to its component fields):
2830
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2831
');
2832
$_$;
2833

    
2834

    
2835
--
2836
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2837
--
2838

    
2839
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2840
type_table (*required*): table to create as the shared base type
2841
';
2842

    
2843

    
2844
--
2845
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2846
--
2847

    
2848
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2849
    LANGUAGE sql
2850
    AS $_$
2851
SELECT util.drop_table($1);
2852
SELECT util.materialize_query($1, $2);
2853
$_$;
2854

    
2855

    
2856
--
2857
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2858
--
2859

    
2860
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2861
idempotent, but repeats action each time
2862
';
2863

    
2864

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

    
2869
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2870
    LANGUAGE sql
2871
    AS $_$
2872
SELECT util.drop_table($1);
2873
SELECT util.materialize_view($1, $2);
2874
$_$;
2875

    
2876

    
2877
--
2878
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2879
--
2880

    
2881
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2882
idempotent, but repeats action each time
2883
';
2884

    
2885

    
2886
--
2887
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2888
--
2889

    
2890
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2891
    LANGUAGE sql
2892
    AS $_$
2893
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2894
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2895
FROM util.col_names($1::text::regtype) f (name);
2896
SELECT NULL::void; -- don't fold away functions called in previous query
2897
$_$;
2898

    
2899

    
2900
--
2901
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2902
--
2903

    
2904
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2905
idempotent
2906
';
2907

    
2908

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

    
2913
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2914
    LANGUAGE sql
2915
    AS $_$
2916
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2917
included in the debug SQL */
2918
SELECT util.rename_relation(util.qual_name($1), $2)
2919
$_$;
2920

    
2921

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

    
2926
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2927
    LANGUAGE sql
2928
    AS $_$
2929
/* 'ALTER TABLE can be used with views too'
2930
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2931
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2932
||quote_ident($2))
2933
$_$;
2934

    
2935

    
2936
--
2937
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2938
--
2939

    
2940
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2941
idempotent
2942
';
2943

    
2944

    
2945
--
2946
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2947
--
2948

    
2949
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2950
    LANGUAGE sql IMMUTABLE
2951
    AS $_$
2952
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2953
$_$;
2954

    
2955

    
2956
--
2957
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2958
--
2959

    
2960
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2961
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 
2962
';
2963

    
2964

    
2965
--
2966
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2967
--
2968

    
2969
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2970
    LANGUAGE sql
2971
    AS $_$
2972
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2973
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2974
SELECT util.set_col_names($1, $2);
2975
$_$;
2976

    
2977

    
2978
--
2979
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2980
--
2981

    
2982
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2983
idempotent.
2984
alters the names table, so it will need to be repopulated after running this function.
2985
';
2986

    
2987

    
2988
--
2989
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2990
--
2991

    
2992
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2993
    LANGUAGE sql
2994
    AS $_$
2995
SELECT util.drop_table($1);
2996
SELECT util.mk_map_table($1);
2997
$_$;
2998

    
2999

    
3000
--
3001
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3002
--
3003

    
3004
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3005
    LANGUAGE sql IMMUTABLE
3006
    AS $_$
3007
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3008
$_$;
3009

    
3010

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

    
3015
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3016
    LANGUAGE sql IMMUTABLE
3017
    AS $_$
3018
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3019
ELSE util.mk_set_search_path(for_printing := true)||$$;
3020
$$ END)||$1
3021
$_$;
3022

    
3023

    
3024
--
3025
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3026
--
3027

    
3028
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3029
    LANGUAGE plpgsql STRICT
3030
    AS $_$
3031
DECLARE
3032
	result text = NULL;
3033
BEGIN
3034
	BEGIN
3035
		result = util.show_create_view(view_);
3036
		PERFORM util.eval($$DROP VIEW $$||view_);
3037
	EXCEPTION
3038
		WHEN undefined_table THEN NULL;
3039
	END;
3040
	RETURN result;
3041
END;
3042
$_$;
3043

    
3044

    
3045
--
3046
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3047
--
3048

    
3049
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3050
    LANGUAGE sql
3051
    AS $_$
3052
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3053
$_$;
3054

    
3055

    
3056
--
3057
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3058
--
3059

    
3060
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3061
    LANGUAGE sql STABLE
3062
    AS $_$
3063
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3064
$_$;
3065

    
3066

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

    
3071
CREATE FUNCTION schema(table_ regclass) RETURNS text
3072
    LANGUAGE sql STABLE
3073
    AS $_$
3074
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3075
$_$;
3076

    
3077

    
3078
--
3079
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3080
--
3081

    
3082
CREATE FUNCTION schema(type regtype) RETURNS text
3083
    LANGUAGE sql STABLE
3084
    AS $_$
3085
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3086
$_$;
3087

    
3088

    
3089
--
3090
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3091
--
3092

    
3093
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3094
    LANGUAGE sql STABLE
3095
    AS $_$
3096
SELECT util.schema(pg_typeof($1))
3097
$_$;
3098

    
3099

    
3100
--
3101
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3102
--
3103

    
3104
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3105
    LANGUAGE sql STABLE
3106
    AS $_$
3107
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3108
$_$;
3109

    
3110

    
3111
--
3112
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3113
--
3114

    
3115
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3116
a schema bundle is a group of schemas with a common prefix
3117
';
3118

    
3119

    
3120
--
3121
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3122
--
3123

    
3124
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3125
    LANGUAGE sql
3126
    AS $_$
3127
SELECT util.schema_rename(old_schema,
3128
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3129
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3130
SELECT NULL::void; -- don't fold away functions called in previous query
3131
$_$;
3132

    
3133

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

    
3138
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3139
    LANGUAGE plpgsql
3140
    AS $$
3141
BEGIN
3142
	-- don't schema_bundle_rm() the schema_bundle to keep!
3143
	IF replace = with_ THEN RETURN; END IF;
3144
	
3145
	PERFORM util.schema_bundle_rm(replace);
3146
	PERFORM util.schema_bundle_rename(with_, replace);
3147
END;
3148
$$;
3149

    
3150

    
3151
--
3152
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3153
--
3154

    
3155
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3156
    LANGUAGE sql
3157
    AS $_$
3158
SELECT util.schema_rm(schema)
3159
FROM util.schema_bundle_get_schemas($1) f (schema);
3160
SELECT NULL::void; -- don't fold away functions called in previous query
3161
$_$;
3162

    
3163

    
3164
--
3165
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3166
--
3167

    
3168
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3169
    LANGUAGE sql STABLE
3170
    AS $_$
3171
SELECT quote_ident(util.schema($1))
3172
$_$;
3173

    
3174

    
3175
--
3176
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3177
--
3178

    
3179
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3180
    LANGUAGE sql IMMUTABLE
3181
    AS $_$
3182
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3183
$_$;
3184

    
3185

    
3186
--
3187
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3188
--
3189

    
3190
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3191
    LANGUAGE sql STABLE
3192
    AS $_$
3193
SELECT oid FROM pg_namespace WHERE nspname = $1
3194
$_$;
3195

    
3196

    
3197
--
3198
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3199
--
3200

    
3201
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3202
    LANGUAGE sql IMMUTABLE
3203
    AS $_$
3204
SELECT util.schema_regexp(schema_anchor := $1)
3205
$_$;
3206

    
3207

    
3208
--
3209
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3210
--
3211

    
3212
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3213
    LANGUAGE sql IMMUTABLE
3214
    AS $_$
3215
SELECT util.str_equality_regexp(util.schema($1))
3216
$_$;
3217

    
3218

    
3219
--
3220
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3221
--
3222

    
3223
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3224
    LANGUAGE sql
3225
    AS $_$
3226
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3227
$_$;
3228

    
3229

    
3230
--
3231
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3232
--
3233

    
3234
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3235
    LANGUAGE plpgsql
3236
    AS $$
3237
BEGIN
3238
	-- don't schema_rm() the schema to keep!
3239
	IF replace = with_ THEN RETURN; END IF;
3240
	
3241
	PERFORM util.schema_rm(replace);
3242
	PERFORM util.schema_rename(with_, replace);
3243
END;
3244
$$;
3245

    
3246

    
3247
--
3248
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3249
--
3250

    
3251
CREATE FUNCTION schema_rm(schema text) RETURNS void
3252
    LANGUAGE sql
3253
    AS $_$
3254
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3255
$_$;
3256

    
3257

    
3258
--
3259
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3260
--
3261

    
3262
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3263
    LANGUAGE sql
3264
    AS $_$
3265
SELECT util.eval(
3266
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3267
$_$;
3268

    
3269

    
3270
--
3271
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3272
--
3273

    
3274
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3275
    LANGUAGE plpgsql STRICT
3276
    AS $_$
3277
DECLARE
3278
    old text[] = ARRAY(SELECT util.col_names(table_));
3279
    new text[] = ARRAY(SELECT util.map_values(names));
3280
BEGIN
3281
    old = old[1:array_length(new, 1)]; -- truncate to same length
3282
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3283
||$$ TO $$||quote_ident(value))
3284
    FROM each(hstore(old, new))
3285
    WHERE value != key -- not same name
3286
    ;
3287
END;
3288
$_$;
3289

    
3290

    
3291
--
3292
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3293
--
3294

    
3295
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3296
idempotent
3297
';
3298

    
3299

    
3300
--
3301
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3302
--
3303

    
3304
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3305
    LANGUAGE plpgsql STRICT
3306
    AS $_$
3307
DECLARE
3308
	row_ util.map;
3309
BEGIN
3310
	-- rename any metadata cols rather than re-adding them with new names
3311
	BEGIN
3312
		PERFORM util.set_col_names(table_, names);
3313
	EXCEPTION
3314
		WHEN array_subscript_error THEN -- selective suppress
3315
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3316
				-- metadata cols not yet added
3317
			ELSE RAISE;
3318
			END IF;
3319
	END;
3320
	
3321
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3322
	LOOP
3323
		PERFORM util.mk_const_col((table_, row_."to"),
3324
			substring(row_."from" from 2));
3325
	END LOOP;
3326
	
3327
	PERFORM util.set_col_names(table_, names);
3328
END;
3329
$_$;
3330

    
3331

    
3332
--
3333
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3334
--
3335

    
3336
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3337
idempotent.
3338
the metadata mappings must be *last* in the names table.
3339
';
3340

    
3341

    
3342
--
3343
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3344
--
3345

    
3346
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3347
    LANGUAGE plpgsql STRICT
3348
    AS $_$
3349
DECLARE
3350
    sql text = $$ALTER TABLE $$||table_||$$
3351
$$||NULLIF(array_to_string(ARRAY(
3352
    SELECT
3353
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3354
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3355
    FROM
3356
    (
3357
        SELECT
3358
          quote_ident(col_name) AS col_name_sql
3359
        , util.col_type((table_, col_name)) AS curr_type
3360
        , type AS target_type
3361
        FROM unnest(col_casts)
3362
    ) s
3363
    WHERE curr_type != target_type
3364
), '
3365
, '), '');
3366
BEGIN
3367
    PERFORM util.debug_print_sql(sql);
3368
    EXECUTE COALESCE(sql, '');
3369
END;
3370
$_$;
3371

    
3372

    
3373
--
3374
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3375
--
3376

    
3377
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3378
idempotent
3379
';
3380

    
3381

    
3382
--
3383
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3384
--
3385

    
3386
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3387
    LANGUAGE sql
3388
    AS $_$
3389
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3390
$_$;
3391

    
3392

    
3393
--
3394
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3395
--
3396

    
3397
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3398
    LANGUAGE sql
3399
    AS $_$
3400
SELECT util.eval(util.mk_set_search_path($1, $2))
3401
$_$;
3402

    
3403

    
3404
--
3405
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3406
--
3407

    
3408
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3409
    LANGUAGE sql STABLE
3410
    AS $_$
3411
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3412
$$||util.show_grants_for($1)
3413
$_$;
3414

    
3415

    
3416
--
3417
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3418
--
3419

    
3420
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3421
    LANGUAGE sql STABLE
3422
    AS $_$
3423
SELECT string_agg(cmd, '')
3424
FROM
3425
(
3426
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3427
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3428
$$ ELSE '' END) AS cmd
3429
	FROM util.grants_users() f (user_)
3430
) s
3431
$_$;
3432

    
3433

    
3434
--
3435
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3436
--
3437

    
3438
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3439
    LANGUAGE sql STABLE
3440
    AS $_$
3441
SELECT oid FROM pg_class
3442
WHERE relkind = ANY($3) AND relname ~ $1
3443
AND util.schema_matches(util.schema(relnamespace), $2)
3444
ORDER BY relname
3445
$_$;
3446

    
3447

    
3448
--
3449
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3450
--
3451

    
3452
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3453
    LANGUAGE sql STABLE
3454
    AS $_$
3455
SELECT oid
3456
FROM pg_type
3457
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3458
ORDER BY typname
3459
$_$;
3460

    
3461

    
3462
--
3463
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3464
--
3465

    
3466
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3467
    LANGUAGE sql STABLE
3468
    AS $_$
3469
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3470
$_$;
3471

    
3472

    
3473
--
3474
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3475
--
3476

    
3477
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3478
    LANGUAGE sql IMMUTABLE
3479
    AS $_$
3480
SELECT '^'||util.regexp_quote($1)||'$'
3481
$_$;
3482

    
3483

    
3484
--
3485
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3486
--
3487

    
3488
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3489
    LANGUAGE plpgsql STABLE STRICT
3490
    AS $_$
3491
DECLARE
3492
    hstore hstore;
3493
BEGIN
3494
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3495
        table_||$$))$$ INTO STRICT hstore;
3496
    RETURN hstore;
3497
END;
3498
$_$;
3499

    
3500

    
3501
--
3502
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3503
--
3504

    
3505
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3506
    LANGUAGE sql STABLE
3507
    AS $_$
3508
SELECT COUNT(*) > 0 FROM pg_constraint
3509
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3510
$_$;
3511

    
3512

    
3513
--
3514
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3515
--
3516

    
3517
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3518
gets whether a status flag is set by the presence of a table constraint
3519
';
3520

    
3521

    
3522
--
3523
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3524
--
3525

    
3526
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3527
    LANGUAGE sql
3528
    AS $_$
3529
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3530
||quote_ident($2)||$$ CHECK (true)$$)
3531
$_$;
3532

    
3533

    
3534
--
3535
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3536
--
3537

    
3538
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3539
stores a status flag by the presence of a table constraint.
3540
idempotent.
3541
';
3542

    
3543

    
3544
--
3545
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3546
--
3547

    
3548
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3549
    LANGUAGE sql STABLE
3550
    AS $_$
3551
SELECT util.table_flag__get($1, 'nulls_mapped')
3552
$_$;
3553

    
3554

    
3555
--
3556
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3557
--
3558

    
3559
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3560
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3561
';
3562

    
3563

    
3564
--
3565
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3566
--
3567

    
3568
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3569
    LANGUAGE sql
3570
    AS $_$
3571
SELECT util.table_flag__set($1, 'nulls_mapped')
3572
$_$;
3573

    
3574

    
3575
--
3576
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3577
--
3578

    
3579
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3580
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3581
idempotent.
3582
';
3583

    
3584

    
3585
--
3586
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3587
--
3588

    
3589
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3590
    LANGUAGE sql
3591
    AS $_$
3592
-- save data before truncating main table
3593
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3594

    
3595
-- repopulate main table w/ copies column
3596
SELECT util.truncate($1);
3597
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3598
SELECT util.populate_table($1, $$
3599
SELECT (table_).*, copies
3600
FROM (
3601
	SELECT table_, COUNT(*) AS copies
3602
	FROM pg_temp.__copy table_
3603
	GROUP BY table_
3604
) s
3605
$$);
3606

    
3607
-- delete temp table so it doesn't stay around until end of connection
3608
SELECT util.drop_table('pg_temp.__copy');
3609
$_$;
3610

    
3611

    
3612
--
3613
-- Name: to_freq(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3614
--
3615

    
3616
CREATE FUNCTION to_freq(table_ regclass, drop_if_always_1 boolean) RETURNS void
3617
    LANGUAGE sql
3618
    AS $_$
3619
SELECT util.to_freq($1);
3620
SELECT util.auto_rm_freq($1);
3621
$_$;
3622

    
3623

    
3624
--
3625
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3626
--
3627

    
3628
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3629
    LANGUAGE plpgsql STRICT
3630
    AS $_$
3631
DECLARE
3632
    row record;
3633
BEGIN
3634
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3635
    LOOP
3636
        IF row.global_name != row.name THEN
3637
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3638
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3639
        END IF;
3640
    END LOOP;
3641
END;
3642
$_$;
3643

    
3644

    
3645
--
3646
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3647
--
3648

    
3649
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3650
idempotent
3651
';
3652

    
3653

    
3654
--
3655
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3656
--
3657

    
3658
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3659
    LANGUAGE sql
3660
    AS $_$
3661
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3662
SELECT NULL::void; -- don't fold away functions called in previous query
3663
$_$;
3664

    
3665

    
3666
--
3667
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3668
--
3669

    
3670
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3671
trims table_ to include only columns in the original data.
3672
idempotent.
3673
';
3674

    
3675

    
3676
--
3677
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3678
--
3679

    
3680
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3681
    LANGUAGE plpgsql STRICT
3682
    AS $_$
3683
BEGIN
3684
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3685
END;
3686
$_$;
3687

    
3688

    
3689
--
3690
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3691
--
3692

    
3693
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3694
idempotent
3695
';
3696

    
3697

    
3698
--
3699
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3700
--
3701

    
3702
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3703
    LANGUAGE sql IMMUTABLE
3704
    AS $_$
3705
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3706
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3707
$_$;
3708

    
3709

    
3710
--
3711
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3712
--
3713

    
3714
CREATE FUNCTION try_create(sql text) RETURNS void
3715
    LANGUAGE plpgsql STRICT
3716
    AS $$
3717
BEGIN
3718
    PERFORM util.eval(sql);
3719
EXCEPTION
3720
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3721
    WHEN undefined_column THEN NULL;
3722
    WHEN duplicate_column THEN NULL;
3723
END;
3724
$$;
3725

    
3726

    
3727
--
3728
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3729
--
3730

    
3731
COMMENT ON FUNCTION try_create(sql text) IS '
3732
idempotent
3733
';
3734

    
3735

    
3736
--
3737
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3738
--
3739

    
3740
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3741
    LANGUAGE sql
3742
    AS $_$
3743
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3744
$_$;
3745

    
3746

    
3747
--
3748
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3749
--
3750

    
3751
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3752
idempotent
3753
';
3754

    
3755

    
3756
--
3757
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3758
--
3759

    
3760
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3761
    LANGUAGE sql IMMUTABLE
3762
    AS $_$
3763
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3764
$_$;
3765

    
3766

    
3767
--
3768
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3769
--
3770

    
3771
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3772
a type''s NOT NULL qualifier
3773
';
3774

    
3775

    
3776
--
3777
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3778
--
3779

    
3780
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3781
    LANGUAGE sql STABLE
3782
    AS $_$
3783
SELECT (attname::text, atttypid)::util.col_cast
3784
FROM pg_attribute
3785
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3786
ORDER BY attnum
3787
$_$;
3788

    
3789

    
3790
--
3791
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3792
--
3793

    
3794
CREATE FUNCTION typeof(value anyelement) RETURNS text
3795
    LANGUAGE sql IMMUTABLE
3796
    AS $_$
3797
SELECT util.qual_name(pg_typeof($1))
3798
$_$;
3799

    
3800

    
3801
--
3802
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3803
--
3804

    
3805
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3806
    LANGUAGE plpgsql STABLE
3807
    AS $_$
3808
DECLARE
3809
    type regtype;
3810
BEGIN
3811
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3812
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3813
    RETURN type;
3814
END;
3815
$_$;
3816

    
3817

    
3818
--
3819
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3820
--
3821

    
3822
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3823
    LANGUAGE sql
3824
    AS $_$
3825
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3826
$_$;
3827

    
3828

    
3829
--
3830
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3831
--
3832

    
3833
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3834
auto-appends util to the search_path to enable use of util operators
3835
';
3836

    
3837

    
3838
--
3839
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3840
--
3841

    
3842
CREATE AGGREGATE all_same(anyelement) (
3843
    SFUNC = all_same_transform,
3844
    STYPE = anyarray,
3845
    FINALFUNC = all_same_final
3846
);
3847

    
3848

    
3849
--
3850
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3851
--
3852

    
3853
COMMENT ON AGGREGATE all_same(anyelement) IS '
3854
includes NULLs in comparison
3855
';
3856

    
3857

    
3858
--
3859
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3860
--
3861

    
3862
CREATE AGGREGATE join_strs(text, text) (
3863
    SFUNC = join_strs_transform,
3864
    STYPE = text
3865
);
3866

    
3867

    
3868
--
3869
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3870
--
3871

    
3872
CREATE OPERATOR %== (
3873
    PROCEDURE = "%==",
3874
    LEFTARG = anyelement,
3875
    RIGHTARG = anyelement
3876
);
3877

    
3878

    
3879
--
3880
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3881
--
3882

    
3883
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3884
returns whether the map-keys of the compared values are the same
3885
(mnemonic: % is the Perl symbol for a hash map)
3886

    
3887
should be overridden for types that store both keys and values
3888

    
3889
used in a FULL JOIN to select which columns to join on
3890
';
3891

    
3892

    
3893
--
3894
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3895
--
3896

    
3897
CREATE OPERATOR -> (
3898
    PROCEDURE = map_get,
3899
    LEFTARG = regclass,
3900
    RIGHTARG = text
3901
);
3902

    
3903

    
3904
--
3905
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3906
--
3907

    
3908
CREATE OPERATOR => (
3909
    PROCEDURE = hstore,
3910
    LEFTARG = text[],
3911
    RIGHTARG = text
3912
);
3913

    
3914

    
3915
--
3916
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3917
--
3918

    
3919
COMMENT ON OPERATOR => (text[], text) IS '
3920
usage: array[''key1'', ...]::text[] => ''value''
3921
';
3922

    
3923

    
3924
--
3925
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3926
--
3927

    
3928
CREATE OPERATOR ?*>= (
3929
    PROCEDURE = is_populated_more_often_than,
3930
    LEFTARG = anyelement,
3931
    RIGHTARG = anyelement
3932
);
3933

    
3934

    
3935
--
3936
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3937
--
3938

    
3939
CREATE OPERATOR ?>= (
3940
    PROCEDURE = is_more_complete_than,
3941
    LEFTARG = anyelement,
3942
    RIGHTARG = anyelement
3943
);
3944

    
3945

    
3946
--
3947
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3948
--
3949

    
3950
CREATE OPERATOR ||% (
3951
    PROCEDURE = concat_esc,
3952
    LEFTARG = text,
3953
    RIGHTARG = text
3954
);
3955

    
3956

    
3957
--
3958
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3959
--
3960

    
3961
COMMENT ON OPERATOR ||% (text, text) IS '
3962
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
3963
';
3964

    
3965

    
3966
--
3967
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3968
--
3969

    
3970
CREATE TABLE map (
3971
    "from" text NOT NULL,
3972
    "to" text,
3973
    filter text,
3974
    notes text
3975
);
3976

    
3977

    
3978
--
3979
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3980
--
3981

    
3982

    
3983

    
3984
--
3985
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3986
--
3987

    
3988

    
3989

    
3990
--
3991
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3992
--
3993

    
3994
ALTER TABLE ONLY map
3995
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3996

    
3997

    
3998
--
3999
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4000
--
4001

    
4002
ALTER TABLE ONLY map
4003
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4004

    
4005

    
4006
--
4007
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4008
--
4009

    
4010
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4011

    
4012

    
4013
--
4014
-- PostgreSQL database dump complete
4015
--
4016

    
(19-19/29)