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(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
686
    LANGUAGE sql
687
    AS $_$
688
SELECT CASE WHEN util.freq_always_1($1, $2)
689
THEN util.drop_column($1, $2, force := true)
690
END
691
$_$;
692

    
693

    
694
--
695
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
696
--
697

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

    
704

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

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

    
720

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

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

    
729

    
730
--
731
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
732
--
733

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

    
745

    
746
--
747
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
748
--
749

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

    
769

    
770
--
771
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
772
--
773

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

    
792

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

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

    
803

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

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

    
812

    
813
--
814
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
815
--
816

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

    
828

    
829
--
830
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
831
--
832

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

    
845

    
846
--
847
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
848
--
849

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

    
859

    
860
--
861
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
862
--
863

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

    
872

    
873
--
874
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
875
--
876

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

    
895

    
896
--
897
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
898
--
899

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

    
906

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

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

    
917

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

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

    
928

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

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

    
939

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

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

    
950

    
951
--
952
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
953
--
954

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

    
972

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

    
977
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
978
idempotent
979
';
980

    
981

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

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

    
992

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

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

    
1005

    
1006
--
1007
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1008
--
1009

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

    
1020

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

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

    
1036

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

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

    
1045

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

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

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

    
1061

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

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

    
1070
col_type_null (*required*): NULL::shared_base_type
1071
';
1072

    
1073

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

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

    
1111

    
1112
--
1113
-- 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: -
1114
--
1115

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

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

    
1132

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

    
1139

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

    
1144
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
1145
    LANGUAGE sql
1146
    AS $_$
1147
SELECT * FROM util.diff($1::text, $2::text, $3,
1148
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1149
$_$;
1150

    
1151

    
1152
--
1153
-- 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: -
1154
--
1155

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

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

    
1162
col_type_null (*required*): NULL::shared_base_type
1163
';
1164

    
1165

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

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

    
1176

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

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

    
1185

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

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

    
1197

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

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

    
1206

    
1207
--
1208
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1209
--
1210

    
1211
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1212
    LANGUAGE sql
1213
    AS $_$
1214
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_
1215
$_$;
1216

    
1217

    
1218
--
1219
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1220
--
1221

    
1222
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1223
idempotent
1224
';
1225

    
1226

    
1227
--
1228
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1229
--
1230

    
1231
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1232
    LANGUAGE sql
1233
    AS $_$
1234
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1235
included in the debug SQL */
1236
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1237
$_$;
1238

    
1239

    
1240
--
1241
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1242
--
1243

    
1244
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1245
    LANGUAGE sql
1246
    AS $_$
1247
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1248
||util._if($3, $$ CASCADE$$, ''::text))
1249
$_$;
1250

    
1251

    
1252
--
1253
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1254
--
1255

    
1256
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1257
idempotent
1258
';
1259

    
1260

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

    
1265
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1266
    LANGUAGE sql
1267
    AS $_$
1268
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1269
$_$;
1270

    
1271

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

    
1276
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1277
    LANGUAGE sql
1278
    AS $_$
1279
SELECT util.drop_relation(relation, $3)
1280
FROM util.show_relations_like($1, $2) relation
1281
;
1282
SELECT NULL::void; -- don't fold away functions called in previous query
1283
$_$;
1284

    
1285

    
1286
--
1287
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1288
--
1289

    
1290
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1291
    LANGUAGE sql
1292
    AS $_$
1293
SELECT util.drop_relation('TABLE', $1, $2)
1294
$_$;
1295

    
1296

    
1297
--
1298
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1299
--
1300

    
1301
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1302
idempotent
1303
';
1304

    
1305

    
1306
--
1307
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1308
--
1309

    
1310
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1311
    LANGUAGE sql
1312
    AS $_$
1313
SELECT util.drop_relation('VIEW', $1, $2)
1314
$_$;
1315

    
1316

    
1317
--
1318
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1319
--
1320

    
1321
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1322
idempotent
1323
';
1324

    
1325

    
1326
--
1327
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1328
--
1329

    
1330
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1331
    LANGUAGE sql IMMUTABLE
1332
    AS $_$
1333
SELECT util.array_fill($1, 0)
1334
$_$;
1335

    
1336

    
1337
--
1338
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1339
--
1340

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

    
1345

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

    
1350
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1351
    LANGUAGE sql IMMUTABLE
1352
    AS $_$
1353
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1354
$_$;
1355

    
1356

    
1357
--
1358
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1359
--
1360

    
1361
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1362
    LANGUAGE sql IMMUTABLE
1363
    AS $_$
1364
SELECT regexp_replace($2, '("?)$', $1||'\1')
1365
$_$;
1366

    
1367

    
1368
--
1369
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1370
--
1371

    
1372
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1373
    LANGUAGE plpgsql
1374
    AS $$
1375
BEGIN
1376
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1377
	EXECUTE sql;
1378
END;
1379
$$;
1380

    
1381

    
1382
--
1383
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1384
--
1385

    
1386
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1387
    LANGUAGE plpgsql
1388
    AS $$
1389
BEGIN
1390
	PERFORM util.debug_print_sql(sql);
1391
	RETURN QUERY EXECUTE sql;
1392
END;
1393
$$;
1394

    
1395

    
1396
--
1397
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1398
--
1399

    
1400
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1401
col_type_null (*required*): NULL::col_type
1402
';
1403

    
1404

    
1405
--
1406
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1407
--
1408

    
1409
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1410
    LANGUAGE plpgsql
1411
    AS $$
1412
BEGIN
1413
	PERFORM util.debug_print_sql(sql);
1414
	RETURN QUERY EXECUTE sql;
1415
END;
1416
$$;
1417

    
1418

    
1419
--
1420
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1421
--
1422

    
1423
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1424
    LANGUAGE plpgsql
1425
    AS $$
1426
BEGIN
1427
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1428
	RETURN QUERY EXECUTE sql;
1429
END;
1430
$$;
1431

    
1432

    
1433
--
1434
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1435
--
1436

    
1437
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1438
    LANGUAGE plpgsql STABLE
1439
    AS $$
1440
DECLARE
1441
	ret_val ret_type_null%TYPE;
1442
BEGIN
1443
	PERFORM util.debug_print_sql(sql);
1444
	EXECUTE sql INTO STRICT ret_val;
1445
	RETURN ret_val;
1446
END;
1447
$$;
1448

    
1449

    
1450
--
1451
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1452
--
1453

    
1454
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1455
ret_type_null: NULL::ret_type
1456
';
1457

    
1458

    
1459
--
1460
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1461
--
1462

    
1463
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1464
    LANGUAGE sql
1465
    AS $_$
1466
SELECT util.eval2val($$SELECT $$||$1, $2)
1467
$_$;
1468

    
1469

    
1470
--
1471
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1472
--
1473

    
1474
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1475
ret_type_null: NULL::ret_type
1476
';
1477

    
1478

    
1479
--
1480
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1481
--
1482

    
1483
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1484
    LANGUAGE sql
1485
    AS $_$
1486
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1487
$_$;
1488

    
1489

    
1490
--
1491
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1492
--
1493

    
1494
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1495
sql: can be NULL, which will be passed through
1496
ret_type_null: NULL::ret_type
1497
';
1498

    
1499

    
1500
--
1501
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1502
--
1503

    
1504
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1505
    LANGUAGE sql STABLE
1506
    AS $_$
1507
SELECT col_name
1508
FROM unnest($2) s (col_name)
1509
WHERE util.col_exists(($1, col_name))
1510
$_$;
1511

    
1512

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

    
1517
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1518
    LANGUAGE sql
1519
    AS $_$
1520
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1521
$_$;
1522

    
1523

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

    
1528
CREATE FUNCTION explain2notice(sql text) RETURNS void
1529
    LANGUAGE sql
1530
    AS $_$
1531
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1532
$_$;
1533

    
1534

    
1535
--
1536
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1537
--
1538

    
1539
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1540
    LANGUAGE sql
1541
    AS $_$
1542
-- newline before and after to visually separate it from other debug info
1543
SELECT $$
1544
EXPLAIN:
1545
$$||util.explain2str($1)||$$
1546
$$
1547
$_$;
1548

    
1549

    
1550
--
1551
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1552
--
1553

    
1554
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1555
    LANGUAGE sql
1556
    AS $_$
1557
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1558
$_$;
1559

    
1560

    
1561
--
1562
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1563
--
1564

    
1565
CREATE FUNCTION explain2str(sql text) RETURNS text
1566
    LANGUAGE sql
1567
    AS $_$
1568
SELECT util.join_strs(explain, $$
1569
$$) FROM util.explain($1)
1570
$_$;
1571

    
1572

    
1573
SET default_tablespace = '';
1574

    
1575
SET default_with_oids = false;
1576

    
1577
--
1578
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1579
--
1580

    
1581
CREATE TABLE explain (
1582
    line text NOT NULL
1583
);
1584

    
1585

    
1586
--
1587
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1588
--
1589

    
1590
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1591
    LANGUAGE sql
1592
    AS $_$
1593
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1594
$$||quote_nullable($1)||$$
1595
)$$)
1596
$_$;
1597

    
1598

    
1599
--
1600
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1601
--
1602

    
1603
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1604
usage:
1605
PERFORM util.explain2table($$
1606
query
1607
$$);
1608
';
1609

    
1610

    
1611
--
1612
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1613
--
1614

    
1615
CREATE FUNCTION first_word(str text) RETURNS text
1616
    LANGUAGE sql IMMUTABLE
1617
    AS $_$
1618
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1619
$_$;
1620

    
1621

    
1622
--
1623
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1624
--
1625

    
1626
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1627
    LANGUAGE sql IMMUTABLE
1628
    AS $_$
1629
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1630
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1631
) END
1632
$_$;
1633

    
1634

    
1635
--
1636
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1637
--
1638

    
1639
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1640
ensures that an array will always have proper non-NULL dimensions
1641
';
1642

    
1643

    
1644
--
1645
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1646
--
1647

    
1648
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1649
    LANGUAGE plpgsql
1650
    AS $_$
1651
DECLARE
1652
	PG_EXCEPTION_DETAIL text;
1653
	recreate_users_cmd text = util.save_drop_views(users);
1654
BEGIN
1655
	PERFORM util.eval(cmd);
1656
	PERFORM util.eval(recreate_users_cmd);
1657
EXCEPTION
1658
WHEN dependent_objects_still_exist THEN
1659
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1660
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1661
	users = array(SELECT * FROM util.regexp_matches_group(
1662
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1663
	IF util.is_empty(users) THEN RAISE; END IF;
1664
	PERFORM util.force_recreate(cmd, users);
1665
END;
1666
$_$;
1667

    
1668

    
1669
--
1670
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1671
--
1672

    
1673
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1674
idempotent
1675

    
1676
users: not necessary to provide this because it will be autopopulated
1677
';
1678

    
1679

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

    
1684
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1685
    LANGUAGE plpgsql STRICT
1686
    AS $_$
1687
DECLARE
1688
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1689
$$||query;
1690
BEGIN
1691
	EXECUTE mk_view;
1692
EXCEPTION
1693
WHEN invalid_table_definition THEN
1694
	IF SQLERRM = 'cannot drop columns from view'
1695
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1696
	THEN
1697
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1698
		EXECUTE mk_view;
1699
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1700
	END IF;
1701
END;
1702
$_$;
1703

    
1704

    
1705
--
1706
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1707
--
1708

    
1709
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1710
idempotent
1711
';
1712

    
1713

    
1714
--
1715
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1716
--
1717

    
1718
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1719
    LANGUAGE sql STABLE
1720
    AS $_$
1721
SELECT util.eval2val(
1722
$$SELECT NOT EXISTS( -- there is no row that is != 1
1723
	SELECT NULL
1724
	FROM $$||$1||$$
1725
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1726
	LIMIT 1
1727
)
1728
$$, NULL::boolean)
1729
$_$;
1730

    
1731

    
1732
--
1733
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1734
--
1735

    
1736
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1737
    LANGUAGE sql STABLE
1738
    AS $_$
1739
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1740
$_$;
1741

    
1742

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

    
1747
CREATE FUNCTION grants_users() RETURNS SETOF text
1748
    LANGUAGE sql IMMUTABLE
1749
    AS $$
1750
VALUES ('bien_read'), ('public_')
1751
$$;
1752

    
1753

    
1754
--
1755
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1756
--
1757

    
1758
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1759
    LANGUAGE sql IMMUTABLE
1760
    AS $_$
1761
SELECT substring($2 for length($1)) = $1
1762
$_$;
1763

    
1764

    
1765
--
1766
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1767
--
1768

    
1769
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1770
    LANGUAGE sql STABLE
1771
    AS $_$
1772
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1773
$_$;
1774

    
1775

    
1776
--
1777
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1778
--
1779

    
1780
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1781
    LANGUAGE sql IMMUTABLE
1782
    AS $_$
1783
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1784
$_$;
1785

    
1786

    
1787
--
1788
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1789
--
1790

    
1791
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1792
avoids repeating the same value for each key
1793
';
1794

    
1795

    
1796
--
1797
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1798
--
1799

    
1800
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1801
    LANGUAGE sql IMMUTABLE
1802
    AS $_$
1803
SELECT COALESCE($1, $2)
1804
$_$;
1805

    
1806

    
1807
--
1808
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1809
--
1810

    
1811
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1812
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1813
';
1814

    
1815

    
1816
--
1817
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1818
--
1819

    
1820
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1821
    LANGUAGE sql
1822
    AS $_$
1823
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1824
$_$;
1825

    
1826

    
1827
--
1828
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1829
--
1830

    
1831
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1832
    LANGUAGE sql STABLE
1833
    AS $_$
1834
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1835
$_$;
1836

    
1837

    
1838
--
1839
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1840
--
1841

    
1842
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1843
    LANGUAGE sql IMMUTABLE
1844
    AS $_$
1845
SELECT util.array_length($1) = 0
1846
$_$;
1847

    
1848

    
1849
--
1850
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1851
--
1852

    
1853
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1854
    LANGUAGE sql IMMUTABLE
1855
    AS $_$
1856
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1857
$_$;
1858

    
1859

    
1860
--
1861
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1862
--
1863

    
1864
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1865
    LANGUAGE sql IMMUTABLE
1866
    AS $_$
1867
SELECT upper(util.first_word($1)) = ANY(
1868
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1869
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1870
)
1871
$_$;
1872

    
1873

    
1874
--
1875
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1876
--
1877

    
1878
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1879
    LANGUAGE sql IMMUTABLE
1880
    AS $_$
1881
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1882
$_$;
1883

    
1884

    
1885
--
1886
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1887
--
1888

    
1889
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1890
    LANGUAGE sql IMMUTABLE
1891
    AS $_$
1892
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1893
$_$;
1894

    
1895

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

    
1900
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1901
    LANGUAGE sql IMMUTABLE
1902
    AS $_$
1903
SELECT upper(util.first_word($1)) = 'SET'
1904
$_$;
1905

    
1906

    
1907
--
1908
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1909
--
1910

    
1911
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1912
    LANGUAGE sql STABLE
1913
    AS $_$
1914
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1915
$_$;
1916

    
1917

    
1918
--
1919
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1920
--
1921

    
1922
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1923
    LANGUAGE sql STABLE
1924
    AS $_$
1925
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1926
$_$;
1927

    
1928

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

    
1933
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1934
    LANGUAGE sql IMMUTABLE STRICT
1935
    AS $_$
1936
SELECT $1 || $3 || $2
1937
$_$;
1938

    
1939

    
1940
--
1941
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1942
--
1943

    
1944
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1945
must be declared STRICT to use the special handling of STRICT aggregating functions
1946
';
1947

    
1948

    
1949
--
1950
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1951
--
1952

    
1953
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1954
    LANGUAGE sql IMMUTABLE
1955
    AS $_$
1956
SELECT $1 -- compare on the entire value
1957
$_$;
1958

    
1959

    
1960
--
1961
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1962
--
1963

    
1964
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1965
    LANGUAGE sql IMMUTABLE
1966
    AS $_$
1967
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1968
$_$;
1969

    
1970

    
1971
--
1972
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1973
--
1974

    
1975
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1976
    LANGUAGE sql IMMUTABLE
1977
    AS $_$
1978
SELECT ltrim($1, $$
1979
$$)
1980
$_$;
1981

    
1982

    
1983
--
1984
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1985
--
1986

    
1987
CREATE FUNCTION map_filter_insert() RETURNS trigger
1988
    LANGUAGE plpgsql
1989
    AS $$
1990
BEGIN
1991
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1992
	RETURN new;
1993
END;
1994
$$;
1995

    
1996

    
1997
--
1998
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1999
--
2000

    
2001
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2002
    LANGUAGE plpgsql STABLE STRICT
2003
    AS $_$
2004
DECLARE
2005
    value text;
2006
BEGIN
2007
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2008
        INTO value USING key;
2009
    RETURN value;
2010
END;
2011
$_$;
2012

    
2013

    
2014
--
2015
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2016
--
2017

    
2018
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2019
    LANGUAGE sql IMMUTABLE
2020
    AS $_$
2021
SELECT util._map(util.nulls_map($1), $2)
2022
$_$;
2023

    
2024

    
2025
--
2026
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2027
--
2028

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

    
2032
[1] inlining of function calls, which is different from constant folding
2033
[2] _map()''s profiling query
2034
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2035
and map_nulls()''s profiling query
2036
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2037
both take ~920 ms.
2038
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.
2039
';
2040

    
2041

    
2042
--
2043
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2044
--
2045

    
2046
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2047
    LANGUAGE plpgsql STABLE STRICT
2048
    AS $_$
2049
BEGIN
2050
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2051
END;
2052
$_$;
2053

    
2054

    
2055
--
2056
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2057
--
2058

    
2059
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2060
    LANGUAGE sql
2061
    AS $_$
2062
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2063
$$||util.ltrim_nl($2));
2064
-- make sure the created table has the correct estimated row count
2065
SELECT util.analyze_($1);
2066

    
2067
SELECT util.append_comment($1, '
2068
contents generated from:
2069
'||util.ltrim_nl($2)||';
2070
');
2071
$_$;
2072

    
2073

    
2074
--
2075
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2076
--
2077

    
2078
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2079
idempotent
2080
';
2081

    
2082

    
2083
--
2084
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2085
--
2086

    
2087
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2088
    LANGUAGE sql
2089
    AS $_$
2090
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2091
$_$;
2092

    
2093

    
2094
--
2095
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2096
--
2097

    
2098
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2099
idempotent
2100
';
2101

    
2102

    
2103
--
2104
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2105
--
2106

    
2107
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2108
    LANGUAGE sql
2109
    AS $_$
2110
SELECT util.create_if_not_exists($$
2111
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2112
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2113
||quote_literal($2)||$$;
2114
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2115
constant
2116
';
2117
$$)
2118
$_$;
2119

    
2120

    
2121
--
2122
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2123
--
2124

    
2125
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2126
idempotent
2127
';
2128

    
2129

    
2130
--
2131
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2132
--
2133

    
2134
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2135
    LANGUAGE plpgsql STRICT
2136
    AS $_$
2137
DECLARE
2138
    type regtype = util.typeof(expr, col.table_::text::regtype);
2139
    col_name_sql text = quote_ident(col.name);
2140
BEGIN
2141
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2142
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2143
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2144
$$||expr||$$;
2145
$$);
2146
END;
2147
$_$;
2148

    
2149

    
2150
--
2151
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2152
--
2153

    
2154
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2155
idempotent
2156
';
2157

    
2158

    
2159
--
2160
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2161
--
2162

    
2163
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
2164
    LANGUAGE sql IMMUTABLE
2165
    AS $_$
2166
SELECT
2167
$$SELECT
2168
$$||$3||$$
2169
FROM      $$||$1||$$ left_
2170
FULL JOIN $$||$2||$$ right_
2171
ON $$||$4||$$
2172
WHERE $$||$5||$$
2173
ORDER BY left_, right_
2174
$$
2175
$_$;
2176

    
2177

    
2178
--
2179
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2180
--
2181

    
2182
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2183
    LANGUAGE sql
2184
    AS $_$
2185
-- keys()
2186
SELECT util.mk_keys_func($1, ARRAY(
2187
SELECT col FROM util.typed_cols($1) col
2188
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2189
));
2190

    
2191
-- values_()
2192
SELECT util.mk_keys_func($1, COALESCE(
2193
	NULLIF(ARRAY(
2194
	SELECT col FROM util.typed_cols($1) col
2195
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2196
	), ARRAY[]::util.col_cast[])
2197
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2198
, 'values_');
2199
$_$;
2200

    
2201

    
2202
--
2203
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2204
--
2205

    
2206
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2207
    LANGUAGE sql
2208
    AS $_$
2209
SELECT util.create_if_not_exists($$
2210
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2211
($$||util.mk_typed_cols_list($2)||$$);
2212
$$);
2213

    
2214
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2215
$_$;
2216

    
2217

    
2218
--
2219
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2220
--
2221

    
2222
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2223
    LANGUAGE sql
2224
    AS $_$
2225
SELECT util.create_if_not_exists($$
2226
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2227
||util.qual_name($1)||$$)
2228
  RETURNS $$||util.qual_name($2)||$$ AS
2229
$BODY1$
2230
SELECT ROW($$||
2231
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2232
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2233
$BODY1$
2234
  LANGUAGE sql IMMUTABLE
2235
  COST 100;
2236
$$);
2237
$_$;
2238

    
2239

    
2240
--
2241
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2242
--
2243

    
2244
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2245
    LANGUAGE sql
2246
    AS $_$
2247
SELECT util.create_if_not_exists($$
2248
CREATE TABLE $$||$1||$$
2249
(
2250
    LIKE util.map INCLUDING ALL
2251
);
2252

    
2253
CREATE TRIGGER map_filter_insert
2254
  BEFORE INSERT
2255
  ON $$||$1||$$
2256
  FOR EACH ROW
2257
  EXECUTE PROCEDURE util.map_filter_insert();
2258
$$)
2259
$_$;
2260

    
2261

    
2262
--
2263
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2264
--
2265

    
2266
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2267
    LANGUAGE sql IMMUTABLE
2268
    AS $_$
2269
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2270
util.qual_name((unnest).type), ''), '')
2271
FROM unnest($1)
2272
$_$;
2273

    
2274

    
2275
--
2276
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2277
--
2278

    
2279
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2280
    LANGUAGE sql IMMUTABLE
2281
    AS $_$
2282
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2283
$_$;
2284

    
2285

    
2286
--
2287
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2288
--
2289

    
2290
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2291
auto-appends util to the search_path to enable use of util operators
2292
';
2293

    
2294

    
2295
--
2296
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2297
--
2298

    
2299
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2300
    LANGUAGE sql IMMUTABLE
2301
    AS $_$
2302
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2303
$_$;
2304

    
2305

    
2306
--
2307
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2308
--
2309

    
2310
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2311
    LANGUAGE sql IMMUTABLE
2312
    AS $_$
2313
/* debug_print_return_value() needed because this function is used with EXECUTE
2314
rather than util.eval() (in order to affect the calling function), so the
2315
search_path would not otherwise be printed */
2316
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2317
||$$ search_path TO $$||$1
2318
$_$;
2319

    
2320

    
2321
--
2322
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2323
--
2324

    
2325
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2326
    LANGUAGE sql
2327
    AS $_$
2328
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2329
$_$;
2330

    
2331

    
2332
--
2333
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2334
--
2335

    
2336
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2337
idempotent
2338
';
2339

    
2340

    
2341
--
2342
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2343
--
2344

    
2345
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2346
    LANGUAGE plpgsql STRICT
2347
    AS $_$
2348
DECLARE
2349
	view_qual_name text = util.qual_name(view_);
2350
BEGIN
2351
	EXECUTE $$
2352
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2353
  RETURNS SETOF $$||view_||$$ AS
2354
$BODY1$
2355
SELECT * FROM $$||view_qual_name||$$
2356
ORDER BY sort_col
2357
LIMIT $1 OFFSET $2
2358
$BODY1$
2359
  LANGUAGE sql STABLE
2360
  COST 100
2361
  ROWS 1000
2362
$$;
2363
	
2364
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2365
END;
2366
$_$;
2367

    
2368

    
2369
--
2370
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2371
--
2372

    
2373
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2374
    LANGUAGE plpgsql STRICT
2375
    AS $_$
2376
DECLARE
2377
	view_qual_name text = util.qual_name(view_);
2378
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2379
BEGIN
2380
	EXECUTE $$
2381
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2382
  RETURNS integer AS
2383
$BODY1$
2384
SELECT $$||quote_ident(row_num_col)||$$
2385
FROM $$||view_qual_name||$$
2386
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2387
LIMIT 1
2388
$BODY1$
2389
  LANGUAGE sql STABLE
2390
  COST 100;
2391
$$;
2392
	
2393
	EXECUTE $$
2394
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2395
  RETURNS SETOF $$||view_||$$ AS
2396
$BODY1$
2397
SELECT * FROM $$||view_qual_name||$$
2398
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2399
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2400
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2401
ORDER BY $$||quote_ident(row_num_col)||$$
2402
$BODY1$
2403
  LANGUAGE sql STABLE
2404
  COST 100
2405
  ROWS 1000
2406
$$;
2407
	
2408
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2409
END;
2410
$_$;
2411

    
2412

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

    
2417
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2418
    LANGUAGE plpgsql STRICT
2419
    AS $_$
2420
DECLARE
2421
	view_qual_name text = util.qual_name(view_);
2422
BEGIN
2423
	EXECUTE $$
2424
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2425
  RETURNS SETOF $$||view_||$$
2426
  SET enable_sort TO 'off'
2427
  AS
2428
$BODY1$
2429
SELECT * FROM $$||view_qual_name||$$($2, $3)
2430
$BODY1$
2431
  LANGUAGE sql STABLE
2432
  COST 100
2433
  ROWS 1000
2434
;
2435
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2436
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2437
If you want to run EXPLAIN and get expanded output, use the regular subset
2438
function instead. (When a config param is set on a function, EXPLAIN produces
2439
just a function scan.)
2440
';
2441
$$;
2442
END;
2443
$_$;
2444

    
2445

    
2446
--
2447
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2448
--
2449

    
2450
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2451
creates subset function which turns off enable_sort
2452
';
2453

    
2454

    
2455
--
2456
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2457
--
2458

    
2459
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2460
    LANGUAGE sql IMMUTABLE
2461
    AS $_$
2462
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2463
util.qual_name((unnest).type), ', '), '')
2464
FROM unnest($1)
2465
$_$;
2466

    
2467

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

    
2472
CREATE FUNCTION name(table_ regclass) RETURNS text
2473
    LANGUAGE sql STABLE
2474
    AS $_$
2475
SELECT relname::text FROM pg_class WHERE oid = $1
2476
$_$;
2477

    
2478

    
2479
--
2480
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2481
--
2482

    
2483
CREATE FUNCTION name(type regtype) RETURNS text
2484
    LANGUAGE sql STABLE
2485
    AS $_$
2486
SELECT typname::text FROM pg_type WHERE oid = $1
2487
$_$;
2488

    
2489

    
2490
--
2491
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2492
--
2493

    
2494
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2495
    LANGUAGE sql IMMUTABLE
2496
    AS $_$
2497
SELECT octet_length($1) >= util.namedatalen() - $2
2498
$_$;
2499

    
2500

    
2501
--
2502
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2503
--
2504

    
2505
CREATE FUNCTION namedatalen() RETURNS integer
2506
    LANGUAGE sql IMMUTABLE
2507
    AS $$
2508
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2509
$$;
2510

    
2511

    
2512
--
2513
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2514
--
2515

    
2516
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2517
    LANGUAGE sql IMMUTABLE
2518
    AS $_$
2519
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2520
$_$;
2521

    
2522

    
2523
--
2524
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2525
--
2526

    
2527
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2528
    LANGUAGE sql IMMUTABLE
2529
    AS $_$
2530
SELECT $1 IS NOT NULL
2531
$_$;
2532

    
2533

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

    
2538
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2539
    LANGUAGE sql IMMUTABLE
2540
    AS $_$
2541
SELECT util.hstore($1, NULL) || '*=>*'
2542
$_$;
2543

    
2544

    
2545
--
2546
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2547
--
2548

    
2549
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2550
for use with _map()
2551
';
2552

    
2553

    
2554
--
2555
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2556
--
2557

    
2558
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2559
    LANGUAGE sql IMMUTABLE
2560
    AS $_$
2561
SELECT $2 + COALESCE($1, 0)
2562
$_$;
2563

    
2564

    
2565
--
2566
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2567
--
2568

    
2569
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2570
    LANGUAGE sql STABLE
2571
    AS $_$
2572
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2573
$_$;
2574

    
2575

    
2576
--
2577
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2578
--
2579

    
2580
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2581
    LANGUAGE sql
2582
    AS $_$
2583
SELECT util.eval($$INSERT INTO $$||$1||$$
2584
$$||util.ltrim_nl($2));
2585
-- make sure the created table has the correct estimated row count
2586
SELECT util.analyze_($1);
2587
$_$;
2588

    
2589

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

    
2594
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2595
    LANGUAGE sql IMMUTABLE
2596
    AS $_$
2597
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2598
$_$;
2599

    
2600

    
2601
--
2602
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2603
--
2604

    
2605
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2606
    LANGUAGE sql
2607
    AS $_$
2608
SELECT util.set_comment($1, concat($2, util.comment($1)))
2609
$_$;
2610

    
2611

    
2612
--
2613
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2614
--
2615

    
2616
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2617
comment: must start and end with a newline
2618
';
2619

    
2620

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

    
2625
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2626
    LANGUAGE sql IMMUTABLE
2627
    AS $_$
2628
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2629
$_$;
2630

    
2631

    
2632
--
2633
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2634
--
2635

    
2636
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2637
    LANGUAGE sql STABLE
2638
    SET search_path TO pg_temp
2639
    AS $_$
2640
SELECT $1::text
2641
$_$;
2642

    
2643

    
2644
--
2645
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2646
--
2647

    
2648
CREATE FUNCTION qual_name(type regtype) RETURNS text
2649
    LANGUAGE sql STABLE
2650
    SET search_path TO pg_temp
2651
    AS $_$
2652
SELECT $1::text
2653
$_$;
2654

    
2655

    
2656
--
2657
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2658
--
2659

    
2660
COMMENT ON FUNCTION qual_name(type regtype) IS '
2661
a type''s schema-qualified name
2662
';
2663

    
2664

    
2665
--
2666
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2667
--
2668

    
2669
CREATE FUNCTION qual_name(type unknown) RETURNS text
2670
    LANGUAGE sql STABLE
2671
    AS $_$
2672
SELECT util.qual_name($1::text::regtype)
2673
$_$;
2674

    
2675

    
2676
--
2677
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2678
--
2679

    
2680
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2681
    LANGUAGE sql IMMUTABLE
2682
    AS $_$
2683
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2684
$_$;
2685

    
2686

    
2687
--
2688
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2689
--
2690

    
2691
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2692
    LANGUAGE sql IMMUTABLE
2693
    AS $_$
2694
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2695
$_$;
2696

    
2697

    
2698
--
2699
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2700
--
2701

    
2702
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2703
    LANGUAGE sql IMMUTABLE
2704
    AS $_$
2705
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2706
$_$;
2707

    
2708

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

    
2713
CREATE FUNCTION raise(type text, msg text) RETURNS void
2714
    LANGUAGE sql IMMUTABLE
2715
    AS $_X$
2716
SELECT util.eval($$
2717
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2718
  RETURNS void AS
2719
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2720
$__BODY1$
2721
BEGIN
2722
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2723
END;
2724
$__BODY1$
2725
  LANGUAGE plpgsql IMMUTABLE
2726
  COST 100;
2727
$$, verbose_ := false);
2728

    
2729
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2730
$_X$;
2731

    
2732

    
2733
--
2734
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2735
--
2736

    
2737
COMMENT ON FUNCTION raise(type text, msg text) IS '
2738
type: a log level from
2739
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2740
or a condition name from
2741
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2742
';
2743

    
2744

    
2745
--
2746
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2747
--
2748

    
2749
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2750
    LANGUAGE sql IMMUTABLE
2751
    AS $_$
2752
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2753
$_$;
2754

    
2755

    
2756
--
2757
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2758
--
2759

    
2760
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2761
    LANGUAGE plpgsql IMMUTABLE STRICT
2762
    AS $$
2763
BEGIN
2764
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2765
END;
2766
$$;
2767

    
2768

    
2769
--
2770
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772

    
2773
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2774
    LANGUAGE sql IMMUTABLE
2775
    AS $_$
2776
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2777
$_$;
2778

    
2779

    
2780
--
2781
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2782
--
2783

    
2784
CREATE FUNCTION regexp_quote(str text) RETURNS text
2785
    LANGUAGE sql IMMUTABLE
2786
    AS $_$
2787
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2788
$_$;
2789

    
2790

    
2791
--
2792
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2793
--
2794

    
2795
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2796
    LANGUAGE sql IMMUTABLE
2797
    AS $_$
2798
SELECT (CASE WHEN right($1, 1) = ')'
2799
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2800
$_$;
2801

    
2802

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

    
2807
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2808
    LANGUAGE sql STABLE
2809
    AS $_$
2810
SELECT util.relation_type(util.relation_type_char($1))
2811
$_$;
2812

    
2813

    
2814
--
2815
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2816
--
2817

    
2818
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2819
    LANGUAGE sql IMMUTABLE
2820
    AS $_$
2821
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2822
$_$;
2823

    
2824

    
2825
--
2826
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2827
--
2828

    
2829
CREATE FUNCTION relation_type(type regtype) RETURNS text
2830
    LANGUAGE sql IMMUTABLE
2831
    AS $$
2832
SELECT 'TYPE'::text
2833
$$;
2834

    
2835

    
2836
--
2837
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2838
--
2839

    
2840
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2841
    LANGUAGE sql STABLE
2842
    AS $_$
2843
SELECT relkind FROM pg_class WHERE oid = $1
2844
$_$;
2845

    
2846

    
2847
--
2848
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2849
--
2850

    
2851
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2852
    LANGUAGE sql
2853
    AS $_$
2854
/* can't have in_table/out_table inherit from *each other*, because inheritance
2855
also causes the rows of the parent table to be included in the child table.
2856
instead, they need to inherit from a common, empty table. */
2857
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2858
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2859
SELECT util.inherit($2, $4);
2860
SELECT util.inherit($3, $4);
2861

    
2862
SELECT util.rematerialize_query($1, $$
2863
SELECT * FROM util.diff(
2864
  $$||util.quote_typed($2)||$$
2865
, $$||util.quote_typed($3)||$$
2866
, NULL::$$||$4||$$)
2867
$$);
2868

    
2869
/* the table unfortunately cannot be *materialized* in human-readable form,
2870
because this would create column name collisions between the two sides */
2871
SELECT util.prepend_comment($1, '
2872
to view this table in human-readable form (with each side''s tuple column
2873
expanded to its component fields):
2874
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2875
');
2876
$_$;
2877

    
2878

    
2879
--
2880
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2881
--
2882

    
2883
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2884
type_table (*required*): table to create as the shared base type
2885
';
2886

    
2887

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

    
2892
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2893
    LANGUAGE sql
2894
    AS $_$
2895
SELECT util.drop_table($1);
2896
SELECT util.materialize_query($1, $2);
2897
$_$;
2898

    
2899

    
2900
--
2901
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2902
--
2903

    
2904
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2905
idempotent, but repeats action each time
2906
';
2907

    
2908

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

    
2913
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2914
    LANGUAGE sql
2915
    AS $_$
2916
SELECT util.drop_table($1);
2917
SELECT util.materialize_view($1, $2);
2918
$_$;
2919

    
2920

    
2921
--
2922
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2923
--
2924

    
2925
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2926
idempotent, but repeats action each time
2927
';
2928

    
2929

    
2930
--
2931
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2932
--
2933

    
2934
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2935
    LANGUAGE sql
2936
    AS $_$
2937
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2938
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2939
FROM util.col_names($1::text::regtype) f (name);
2940
SELECT NULL::void; -- don't fold away functions called in previous query
2941
$_$;
2942

    
2943

    
2944
--
2945
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2946
--
2947

    
2948
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2949
idempotent
2950
';
2951

    
2952

    
2953
--
2954
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2955
--
2956

    
2957
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2958
    LANGUAGE sql
2959
    AS $_$
2960
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2961
included in the debug SQL */
2962
SELECT util.rename_relation(util.qual_name($1), $2)
2963
$_$;
2964

    
2965

    
2966
--
2967
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2968
--
2969

    
2970
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2971
    LANGUAGE sql
2972
    AS $_$
2973
/* 'ALTER TABLE can be used with views too'
2974
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2975
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2976
||quote_ident($2))
2977
$_$;
2978

    
2979

    
2980
--
2981
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2982
--
2983

    
2984
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2985
idempotent
2986
';
2987

    
2988

    
2989
--
2990
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2991
--
2992

    
2993
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2994
    LANGUAGE sql IMMUTABLE
2995
    AS $_$
2996
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2997
$_$;
2998

    
2999

    
3000
--
3001
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3002
--
3003

    
3004
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3005
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 
3006
';
3007

    
3008

    
3009
--
3010
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3011
--
3012

    
3013
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3014
    LANGUAGE sql
3015
    AS $_$
3016
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3017
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3018
SELECT util.set_col_names($1, $2);
3019
$_$;
3020

    
3021

    
3022
--
3023
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3024
--
3025

    
3026
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3027
idempotent.
3028
alters the names table, so it will need to be repopulated after running this function.
3029
';
3030

    
3031

    
3032
--
3033
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3034
--
3035

    
3036
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3037
    LANGUAGE sql
3038
    AS $_$
3039
SELECT util.drop_table($1);
3040
SELECT util.mk_map_table($1);
3041
$_$;
3042

    
3043

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

    
3048
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3049
    LANGUAGE sql IMMUTABLE
3050
    AS $_$
3051
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3052
$_$;
3053

    
3054

    
3055
--
3056
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3057
--
3058

    
3059
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3060
    LANGUAGE sql IMMUTABLE
3061
    AS $_$
3062
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3063
ELSE util.mk_set_search_path(for_printing := true)||$$;
3064
$$ END)||$1
3065
$_$;
3066

    
3067

    
3068
--
3069
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3070
--
3071

    
3072
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3073
    LANGUAGE plpgsql STRICT
3074
    AS $_$
3075
DECLARE
3076
	result text = NULL;
3077
BEGIN
3078
	BEGIN
3079
		result = util.show_create_view(view_);
3080
		PERFORM util.eval($$DROP VIEW $$||view_);
3081
	EXCEPTION
3082
		WHEN undefined_table THEN NULL;
3083
	END;
3084
	RETURN result;
3085
END;
3086
$_$;
3087

    
3088

    
3089
--
3090
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3091
--
3092

    
3093
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3094
    LANGUAGE sql
3095
    AS $_$
3096
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3097
$_$;
3098

    
3099

    
3100
--
3101
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3102
--
3103

    
3104
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3105
    LANGUAGE sql STABLE
3106
    AS $_$
3107
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3108
$_$;
3109

    
3110

    
3111
--
3112
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3113
--
3114

    
3115
CREATE FUNCTION schema(table_ regclass) RETURNS text
3116
    LANGUAGE sql STABLE
3117
    AS $_$
3118
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3119
$_$;
3120

    
3121

    
3122
--
3123
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3124
--
3125

    
3126
CREATE FUNCTION schema(type regtype) RETURNS text
3127
    LANGUAGE sql STABLE
3128
    AS $_$
3129
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3130
$_$;
3131

    
3132

    
3133
--
3134
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3135
--
3136

    
3137
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3138
    LANGUAGE sql STABLE
3139
    AS $_$
3140
SELECT util.schema(pg_typeof($1))
3141
$_$;
3142

    
3143

    
3144
--
3145
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3146
--
3147

    
3148
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3149
    LANGUAGE sql STABLE
3150
    AS $_$
3151
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3152
$_$;
3153

    
3154

    
3155
--
3156
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3157
--
3158

    
3159
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3160
a schema bundle is a group of schemas with a common prefix
3161
';
3162

    
3163

    
3164
--
3165
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3166
--
3167

    
3168
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3169
    LANGUAGE sql
3170
    AS $_$
3171
SELECT util.schema_rename(old_schema,
3172
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3173
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3174
SELECT NULL::void; -- don't fold away functions called in previous query
3175
$_$;
3176

    
3177

    
3178
--
3179
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3180
--
3181

    
3182
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3183
    LANGUAGE plpgsql
3184
    AS $$
3185
BEGIN
3186
	-- don't schema_bundle_rm() the schema_bundle to keep!
3187
	IF replace = with_ THEN RETURN; END IF;
3188
	
3189
	PERFORM util.schema_bundle_rm(replace);
3190
	PERFORM util.schema_bundle_rename(with_, replace);
3191
END;
3192
$$;
3193

    
3194

    
3195
--
3196
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3197
--
3198

    
3199
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3200
    LANGUAGE sql
3201
    AS $_$
3202
SELECT util.schema_rm(schema)
3203
FROM util.schema_bundle_get_schemas($1) f (schema);
3204
SELECT NULL::void; -- don't fold away functions called in previous query
3205
$_$;
3206

    
3207

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

    
3212
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3213
    LANGUAGE sql STABLE
3214
    AS $_$
3215
SELECT quote_ident(util.schema($1))
3216
$_$;
3217

    
3218

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

    
3223
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3224
    LANGUAGE sql IMMUTABLE
3225
    AS $_$
3226
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3227
$_$;
3228

    
3229

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

    
3234
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3235
    LANGUAGE sql STABLE
3236
    AS $_$
3237
SELECT oid FROM pg_namespace WHERE nspname = $1
3238
$_$;
3239

    
3240

    
3241
--
3242
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3243
--
3244

    
3245
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3246
    LANGUAGE sql IMMUTABLE
3247
    AS $_$
3248
SELECT util.schema_regexp(schema_anchor := $1)
3249
$_$;
3250

    
3251

    
3252
--
3253
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3254
--
3255

    
3256
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3257
    LANGUAGE sql IMMUTABLE
3258
    AS $_$
3259
SELECT util.str_equality_regexp(util.schema($1))
3260
$_$;
3261

    
3262

    
3263
--
3264
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3265
--
3266

    
3267
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3268
    LANGUAGE sql
3269
    AS $_$
3270
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3271
$_$;
3272

    
3273

    
3274
--
3275
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3276
--
3277

    
3278
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3279
    LANGUAGE plpgsql
3280
    AS $$
3281
BEGIN
3282
	-- don't schema_rm() the schema to keep!
3283
	IF replace = with_ THEN RETURN; END IF;
3284
	
3285
	PERFORM util.schema_rm(replace);
3286
	PERFORM util.schema_rename(with_, replace);
3287
END;
3288
$$;
3289

    
3290

    
3291
--
3292
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3293
--
3294

    
3295
CREATE FUNCTION schema_rm(schema text) RETURNS void
3296
    LANGUAGE sql
3297
    AS $_$
3298
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3299
$_$;
3300

    
3301

    
3302
--
3303
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3304
--
3305

    
3306
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3307
    LANGUAGE sql
3308
    AS $_$
3309
SELECT util.eval(
3310
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3311
$_$;
3312

    
3313

    
3314
--
3315
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3316
--
3317

    
3318
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3319
    LANGUAGE plpgsql STRICT
3320
    AS $_$
3321
DECLARE
3322
    old text[] = ARRAY(SELECT util.col_names(table_));
3323
    new text[] = ARRAY(SELECT util.map_values(names));
3324
BEGIN
3325
    old = old[1:array_length(new, 1)]; -- truncate to same length
3326
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3327
||$$ TO $$||quote_ident(value))
3328
    FROM each(hstore(old, new))
3329
    WHERE value != key -- not same name
3330
    ;
3331
END;
3332
$_$;
3333

    
3334

    
3335
--
3336
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3337
--
3338

    
3339
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3340
idempotent
3341
';
3342

    
3343

    
3344
--
3345
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3346
--
3347

    
3348
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3349
    LANGUAGE plpgsql STRICT
3350
    AS $_$
3351
DECLARE
3352
	row_ util.map;
3353
BEGIN
3354
	-- rename any metadata cols rather than re-adding them with new names
3355
	BEGIN
3356
		PERFORM util.set_col_names(table_, names);
3357
	EXCEPTION
3358
		WHEN array_subscript_error THEN -- selective suppress
3359
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3360
				-- metadata cols not yet added
3361
			ELSE RAISE;
3362
			END IF;
3363
	END;
3364
	
3365
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3366
	LOOP
3367
		PERFORM util.mk_const_col((table_, row_."to"),
3368
			substring(row_."from" from 2));
3369
	END LOOP;
3370
	
3371
	PERFORM util.set_col_names(table_, names);
3372
END;
3373
$_$;
3374

    
3375

    
3376
--
3377
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3378
--
3379

    
3380
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3381
idempotent.
3382
the metadata mappings must be *last* in the names table.
3383
';
3384

    
3385

    
3386
--
3387
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3388
--
3389

    
3390
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3391
    LANGUAGE plpgsql STRICT
3392
    AS $_$
3393
DECLARE
3394
    sql text = $$ALTER TABLE $$||table_||$$
3395
$$||NULLIF(array_to_string(ARRAY(
3396
    SELECT
3397
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3398
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3399
    FROM
3400
    (
3401
        SELECT
3402
          quote_ident(col_name) AS col_name_sql
3403
        , util.col_type((table_, col_name)) AS curr_type
3404
        , type AS target_type
3405
        FROM unnest(col_casts)
3406
    ) s
3407
    WHERE curr_type != target_type
3408
), '
3409
, '), '');
3410
BEGIN
3411
    PERFORM util.debug_print_sql(sql);
3412
    EXECUTE COALESCE(sql, '');
3413
END;
3414
$_$;
3415

    
3416

    
3417
--
3418
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3419
--
3420

    
3421
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3422
idempotent
3423
';
3424

    
3425

    
3426
--
3427
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3428
--
3429

    
3430
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3431
    LANGUAGE sql
3432
    AS $_$
3433
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3434
$_$;
3435

    
3436

    
3437
--
3438
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3439
--
3440

    
3441
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3442
    LANGUAGE sql
3443
    AS $_$
3444
SELECT util.eval(util.mk_set_search_path($1, $2))
3445
$_$;
3446

    
3447

    
3448
--
3449
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3450
--
3451

    
3452
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3453
    LANGUAGE sql STABLE
3454
    AS $_$
3455
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3456
$$||util.show_grants_for($1)
3457
$_$;
3458

    
3459

    
3460
--
3461
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3462
--
3463

    
3464
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3465
    LANGUAGE sql STABLE
3466
    AS $_$
3467
SELECT string_agg(cmd, '')
3468
FROM
3469
(
3470
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3471
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3472
$$ ELSE '' END) AS cmd
3473
	FROM util.grants_users() f (user_)
3474
) s
3475
$_$;
3476

    
3477

    
3478
--
3479
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3480
--
3481

    
3482
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3483
    LANGUAGE sql STABLE
3484
    AS $_$
3485
SELECT oid FROM pg_class
3486
WHERE relkind = ANY($3) AND relname ~ $1
3487
AND util.schema_matches(util.schema(relnamespace), $2)
3488
ORDER BY relname
3489
$_$;
3490

    
3491

    
3492
--
3493
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3494
--
3495

    
3496
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3497
    LANGUAGE sql STABLE
3498
    AS $_$
3499
SELECT oid
3500
FROM pg_type
3501
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3502
ORDER BY typname
3503
$_$;
3504

    
3505

    
3506
--
3507
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3508
--
3509

    
3510
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3511
    LANGUAGE sql STABLE
3512
    AS $_$
3513
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3514
$_$;
3515

    
3516

    
3517
--
3518
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3519
--
3520

    
3521
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3522
    LANGUAGE sql IMMUTABLE
3523
    AS $_$
3524
SELECT '^'||util.regexp_quote($1)||'$'
3525
$_$;
3526

    
3527

    
3528
--
3529
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3530
--
3531

    
3532
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3533
    LANGUAGE plpgsql STABLE STRICT
3534
    AS $_$
3535
DECLARE
3536
    hstore hstore;
3537
BEGIN
3538
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3539
        table_||$$))$$ INTO STRICT hstore;
3540
    RETURN hstore;
3541
END;
3542
$_$;
3543

    
3544

    
3545
--
3546
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3547
--
3548

    
3549
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3550
    LANGUAGE sql STABLE
3551
    AS $_$
3552
SELECT COUNT(*) > 0 FROM pg_constraint
3553
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3554
$_$;
3555

    
3556

    
3557
--
3558
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3559
--
3560

    
3561
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3562
gets whether a status flag is set by the presence of a table constraint
3563
';
3564

    
3565

    
3566
--
3567
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3568
--
3569

    
3570
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3571
    LANGUAGE sql
3572
    AS $_$
3573
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3574
||quote_ident($2)||$$ CHECK (true)$$)
3575
$_$;
3576

    
3577

    
3578
--
3579
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3580
--
3581

    
3582
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3583
stores a status flag by the presence of a table constraint.
3584
idempotent.
3585
';
3586

    
3587

    
3588
--
3589
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3590
--
3591

    
3592
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3593
    LANGUAGE sql STABLE
3594
    AS $_$
3595
SELECT util.table_flag__get($1, 'nulls_mapped')
3596
$_$;
3597

    
3598

    
3599
--
3600
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3601
--
3602

    
3603
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3604
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3605
';
3606

    
3607

    
3608
--
3609
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3610
--
3611

    
3612
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3613
    LANGUAGE sql
3614
    AS $_$
3615
SELECT util.table_flag__set($1, 'nulls_mapped')
3616
$_$;
3617

    
3618

    
3619
--
3620
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3621
--
3622

    
3623
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3624
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3625
idempotent.
3626
';
3627

    
3628

    
3629
--
3630
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3631
--
3632

    
3633
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3634
    LANGUAGE sql
3635
    AS $_$
3636
-- save data before truncating main table
3637
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3638

    
3639
-- repopulate main table w/ copies column
3640
SELECT util.truncate($1);
3641
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3642
SELECT util.populate_table($1, $$
3643
SELECT (table_).*, copies
3644
FROM (
3645
	SELECT table_, COUNT(*) AS copies
3646
	FROM pg_temp.__copy table_
3647
	GROUP BY table_
3648
) s
3649
$$);
3650

    
3651
-- delete temp table so it doesn't stay around until end of connection
3652
SELECT util.drop_table('pg_temp.__copy');
3653
$_$;
3654

    
3655

    
3656
--
3657
-- Name: to_freq(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3658
--
3659

    
3660
CREATE FUNCTION to_freq(table_ regclass, drop_if_always_1 boolean) RETURNS void
3661
    LANGUAGE sql
3662
    AS $_$
3663
SELECT util.to_freq($1);
3664
SELECT util.auto_rm_freq(ARRAY[$1]);
3665
$_$;
3666

    
3667

    
3668
--
3669
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3670
--
3671

    
3672
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3673
    LANGUAGE plpgsql STRICT
3674
    AS $_$
3675
DECLARE
3676
    row record;
3677
BEGIN
3678
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3679
    LOOP
3680
        IF row.global_name != row.name THEN
3681
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3682
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3683
        END IF;
3684
    END LOOP;
3685
END;
3686
$_$;
3687

    
3688

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

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

    
3697

    
3698
--
3699
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3700
--
3701

    
3702
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3703
    LANGUAGE sql
3704
    AS $_$
3705
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3706
SELECT NULL::void; -- don't fold away functions called in previous query
3707
$_$;
3708

    
3709

    
3710
--
3711
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3712
--
3713

    
3714
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3715
trims table_ to include only columns in the original data.
3716
idempotent.
3717
';
3718

    
3719

    
3720
--
3721
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3722
--
3723

    
3724
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3725
    LANGUAGE plpgsql STRICT
3726
    AS $_$
3727
BEGIN
3728
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3729
END;
3730
$_$;
3731

    
3732

    
3733
--
3734
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3735
--
3736

    
3737
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3738
idempotent
3739
';
3740

    
3741

    
3742
--
3743
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3744
--
3745

    
3746
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3747
    LANGUAGE sql IMMUTABLE
3748
    AS $_$
3749
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3750
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3751
$_$;
3752

    
3753

    
3754
--
3755
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3756
--
3757

    
3758
CREATE FUNCTION try_create(sql text) RETURNS void
3759
    LANGUAGE plpgsql STRICT
3760
    AS $$
3761
BEGIN
3762
	PERFORM util.eval(sql);
3763
EXCEPTION
3764
	/* trying to add NOT NULL column to parent table, which cascades to child
3765
	table whose values for the new column will be NULL */
3766
	WHEN not_null_violation THEN NULL;
3767
	WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3768
	WHEN undefined_column THEN NULL;
3769
	WHEN duplicate_column THEN NULL;
3770
END;
3771
$$;
3772

    
3773

    
3774
--
3775
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3776
--
3777

    
3778
COMMENT ON FUNCTION try_create(sql text) IS '
3779
idempotent
3780
';
3781

    
3782

    
3783
--
3784
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3785
--
3786

    
3787
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3788
    LANGUAGE sql
3789
    AS $_$
3790
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3791
$_$;
3792

    
3793

    
3794
--
3795
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3796
--
3797

    
3798
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3799
idempotent
3800
';
3801

    
3802

    
3803
--
3804
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3805
--
3806

    
3807
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3808
    LANGUAGE sql IMMUTABLE
3809
    AS $_$
3810
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3811
$_$;
3812

    
3813

    
3814
--
3815
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3816
--
3817

    
3818
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3819
a type''s NOT NULL qualifier
3820
';
3821

    
3822

    
3823
--
3824
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3825
--
3826

    
3827
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3828
    LANGUAGE sql STABLE
3829
    AS $_$
3830
SELECT (attname::text, atttypid)::util.col_cast
3831
FROM pg_attribute
3832
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3833
ORDER BY attnum
3834
$_$;
3835

    
3836

    
3837
--
3838
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3839
--
3840

    
3841
CREATE FUNCTION typeof(value anyelement) RETURNS text
3842
    LANGUAGE sql IMMUTABLE
3843
    AS $_$
3844
SELECT util.qual_name(pg_typeof($1))
3845
$_$;
3846

    
3847

    
3848
--
3849
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3850
--
3851

    
3852
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3853
    LANGUAGE plpgsql STABLE
3854
    AS $_$
3855
DECLARE
3856
    type regtype;
3857
BEGIN
3858
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3859
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3860
    RETURN type;
3861
END;
3862
$_$;
3863

    
3864

    
3865
--
3866
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3867
--
3868

    
3869
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3870
    LANGUAGE sql
3871
    AS $_$
3872
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3873
$_$;
3874

    
3875

    
3876
--
3877
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3878
--
3879

    
3880
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3881
auto-appends util to the search_path to enable use of util operators
3882
';
3883

    
3884

    
3885
--
3886
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3887
--
3888

    
3889
CREATE AGGREGATE all_same(anyelement) (
3890
    SFUNC = all_same_transform,
3891
    STYPE = anyarray,
3892
    FINALFUNC = all_same_final
3893
);
3894

    
3895

    
3896
--
3897
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3898
--
3899

    
3900
COMMENT ON AGGREGATE all_same(anyelement) IS '
3901
includes NULLs in comparison
3902
';
3903

    
3904

    
3905
--
3906
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3907
--
3908

    
3909
CREATE AGGREGATE join_strs(text, text) (
3910
    SFUNC = join_strs_transform,
3911
    STYPE = text
3912
);
3913

    
3914

    
3915
--
3916
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3917
--
3918

    
3919
CREATE OPERATOR %== (
3920
    PROCEDURE = "%==",
3921
    LEFTARG = anyelement,
3922
    RIGHTARG = anyelement
3923
);
3924

    
3925

    
3926
--
3927
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3928
--
3929

    
3930
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3931
returns whether the map-keys of the compared values are the same
3932
(mnemonic: % is the Perl symbol for a hash map)
3933

    
3934
should be overridden for types that store both keys and values
3935

    
3936
used in a FULL JOIN to select which columns to join on
3937
';
3938

    
3939

    
3940
--
3941
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3942
--
3943

    
3944
CREATE OPERATOR -> (
3945
    PROCEDURE = map_get,
3946
    LEFTARG = regclass,
3947
    RIGHTARG = text
3948
);
3949

    
3950

    
3951
--
3952
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3953
--
3954

    
3955
CREATE OPERATOR => (
3956
    PROCEDURE = hstore,
3957
    LEFTARG = text[],
3958
    RIGHTARG = text
3959
);
3960

    
3961

    
3962
--
3963
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3964
--
3965

    
3966
COMMENT ON OPERATOR => (text[], text) IS '
3967
usage: array[''key1'', ...]::text[] => ''value''
3968
';
3969

    
3970

    
3971
--
3972
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3973
--
3974

    
3975
CREATE OPERATOR ?*>= (
3976
    PROCEDURE = is_populated_more_often_than,
3977
    LEFTARG = anyelement,
3978
    RIGHTARG = anyelement
3979
);
3980

    
3981

    
3982
--
3983
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3984
--
3985

    
3986
CREATE OPERATOR ?>= (
3987
    PROCEDURE = is_more_complete_than,
3988
    LEFTARG = anyelement,
3989
    RIGHTARG = anyelement
3990
);
3991

    
3992

    
3993
--
3994
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3995
--
3996

    
3997
CREATE OPERATOR ||% (
3998
    PROCEDURE = concat_esc,
3999
    LEFTARG = text,
4000
    RIGHTARG = text
4001
);
4002

    
4003

    
4004
--
4005
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4006
--
4007

    
4008
COMMENT ON OPERATOR ||% (text, text) IS '
4009
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4010
';
4011

    
4012

    
4013
--
4014
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4015
--
4016

    
4017
CREATE TABLE map (
4018
    "from" text NOT NULL,
4019
    "to" text,
4020
    filter text,
4021
    notes text
4022
);
4023

    
4024

    
4025
--
4026
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4027
--
4028

    
4029

    
4030

    
4031
--
4032
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4033
--
4034

    
4035

    
4036

    
4037
--
4038
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4039
--
4040

    
4041
ALTER TABLE ONLY map
4042
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4043

    
4044

    
4045
--
4046
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4047
--
4048

    
4049
ALTER TABLE ONLY map
4050
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4051

    
4052

    
4053
--
4054
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4055
--
4056

    
4057
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4058

    
4059

    
4060
--
4061
-- PostgreSQL database dump complete
4062
--
4063

    
(19-19/29)