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.rm_freq($1, $2)
690
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
691
END
692
$_$;
693

    
694

    
695
--
696
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
697
--
698

    
699
CREATE FUNCTION "cast"(value text, ret_type_null anyelement) RETURNS anyelement
700
    LANGUAGE plpgsql IMMUTABLE
701
    AS $$
702
/* must use LANGUAGE plpgsql because LANGUAGE sql does not assignment-cast the
703
return value, causing a type mismatch */
704
BEGIN
705
	-- will then be assignment-cast to return type via INOUT
706
	RETURN value::cstring;
707
END;
708
$$;
709

    
710

    
711
--
712
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
713
--
714

    
715
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
716
allows casting to an arbitrary type without eval()
717

    
718
usage:
719
SELECT util.cast(''value'', NULL::integer);
720

    
721
note that there does *not* need to be a cast from text to the output type,
722
because an INOUT cast is used instead
723
(http://www.postgresql.org/docs/9.3/static/sql-createcast.html#AEN69507)
724

    
725
ret_type_null: NULL::ret_type
726
';
727

    
728

    
729
--
730
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
731
--
732

    
733
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
734
    LANGUAGE sql STABLE
735
    AS $_$
736
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
737
$_$;
738

    
739

    
740
--
741
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
742
--
743

    
744
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
745
    LANGUAGE plpgsql STRICT
746
    AS $_$
747
BEGIN
748
    -- not yet clustered (ARRAY[] compares NULLs literally)
749
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
750
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
751
    END IF;
752
END;
753
$_$;
754

    
755

    
756
--
757
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
758
--
759

    
760
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
761
idempotent
762
';
763

    
764

    
765
--
766
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
767
--
768

    
769
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
770
    LANGUAGE sql IMMUTABLE
771
    AS $_$
772
SELECT value
773
FROM unnest($1) value
774
WHERE value IS NOT NULL
775
LIMIT 1
776
$_$;
777

    
778

    
779
--
780
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
781
--
782

    
783
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
784
uses:
785
* coalescing array elements or rows together
786
* forcing evaluation of all values of a COALESCE()
787
';
788

    
789

    
790
--
791
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
792
--
793

    
794
CREATE FUNCTION col__min(col col_ref) RETURNS integer
795
    LANGUAGE sql STABLE
796
    AS $_$
797
SELECT util.eval2val($$
798
SELECT $$||quote_ident($1.name)||$$
799
FROM $$||$1.table_||$$
800
ORDER BY $$||quote_ident($1.name)||$$ ASC
801
LIMIT 1
802
$$, NULL::integer)
803
$_$;
804

    
805

    
806
--
807
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
808
--
809

    
810
CREATE FUNCTION col_comment(col col_ref) RETURNS text
811
    LANGUAGE plpgsql STABLE STRICT
812
    AS $$
813
DECLARE
814
	comment text;
815
BEGIN
816
	SELECT description
817
	FROM pg_attribute
818
	LEFT JOIN pg_description ON objoid = attrelid
819
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
820
	WHERE attrelid = col.table_ AND attname = col.name
821
	INTO STRICT comment
822
	;
823
	RETURN comment;
824
EXCEPTION
825
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
826
END;
827
$$;
828

    
829

    
830
--
831
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
832
--
833

    
834
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
835
    LANGUAGE plpgsql STABLE STRICT
836
    AS $$
837
DECLARE
838
	default_sql text;
839
BEGIN
840
	SELECT adsrc
841
	FROM pg_attribute
842
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
843
	WHERE attrelid = col.table_ AND attname = col.name
844
	INTO STRICT default_sql
845
	;
846
	RETURN default_sql;
847
EXCEPTION
848
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
849
END;
850
$$;
851

    
852

    
853
--
854
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
855
--
856

    
857
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
858
    LANGUAGE sql STABLE
859
    AS $_$
860
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
861
$_$;
862

    
863

    
864
--
865
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
866
--
867

    
868
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
869
ret_type_null: NULL::ret_type
870
';
871

    
872

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

    
877
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
878
    LANGUAGE plpgsql STRICT
879
    AS $$
880
BEGIN
881
    PERFORM util.col_type(col);
882
    RETURN true;
883
EXCEPTION
884
    WHEN undefined_column THEN RETURN false;
885
END;
886
$$;
887

    
888

    
889
--
890
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
891
--
892

    
893
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
894
    LANGUAGE plpgsql STABLE STRICT
895
    AS $$
896
DECLARE
897
    prefix text := util.name(type)||'.';
898
BEGIN
899
    RETURN QUERY
900
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
901
        FROM util.col_names(type) f (name_);
902
END;
903
$$;
904

    
905

    
906
--
907
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
908
--
909

    
910
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
911
    LANGUAGE sql STABLE
912
    AS $_$
913
SELECT attname::text
914
FROM pg_attribute
915
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
916
ORDER BY attnum
917
$_$;
918

    
919

    
920
--
921
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
922
--
923

    
924
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
925
    LANGUAGE plpgsql STABLE STRICT
926
    AS $_$
927
BEGIN
928
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
929
END;
930
$_$;
931

    
932

    
933
--
934
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
935
--
936

    
937
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
938
    LANGUAGE plpgsql STABLE STRICT
939
    AS $$
940
DECLARE
941
    type regtype;
942
BEGIN
943
    SELECT atttypid FROM pg_attribute
944
    WHERE attrelid = col.table_ AND attname = col.name
945
    INTO STRICT type
946
    ;
947
    RETURN type;
948
EXCEPTION
949
    WHEN no_data_found THEN
950
        RAISE undefined_column USING MESSAGE =
951
            concat('undefined column: ', col.name);
952
END;
953
$$;
954

    
955

    
956
--
957
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
958
--
959

    
960
CREATE FUNCTION comment(element oid) RETURNS text
961
    LANGUAGE sql STABLE
962
    AS $_$
963
SELECT description FROM pg_description WHERE objoid = $1
964
$_$;
965

    
966

    
967
--
968
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
969
--
970

    
971
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
972
    LANGUAGE sql IMMUTABLE
973
    AS $_$
974
SELECT util.esc_name__append($2, $1)
975
$_$;
976

    
977

    
978
--
979
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
980
--
981

    
982
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
983
    LANGUAGE sql IMMUTABLE
984
    AS $_$
985
SELECT position($1 in $2) > 0 /*1-based offset*/
986
$_$;
987

    
988

    
989
--
990
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
991
--
992

    
993
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
994
    LANGUAGE sql
995
    AS $_$
996
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
997
$_$;
998

    
999

    
1000
--
1001
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1002
--
1003

    
1004
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1005
    LANGUAGE sql
1006
    AS $_$
1007
SELECT util.materialize_view($2, $1)
1008
$_$;
1009

    
1010

    
1011
--
1012
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
1013
--
1014

    
1015
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
1016
    LANGUAGE plpgsql STRICT
1017
    AS $$
1018
BEGIN
1019
	PERFORM util.eval(sql);
1020
EXCEPTION
1021
WHEN   duplicate_table
1022
	OR duplicate_object -- eg. constraint
1023
	OR duplicate_column
1024
	OR duplicate_function
1025
THEN NULL;
1026
WHEN invalid_table_definition THEN
1027
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1028
	ELSE RAISE;
1029
	END IF;
1030
END;
1031
$$;
1032

    
1033

    
1034
--
1035
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
1036
--
1037

    
1038
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
1039
idempotent
1040
';
1041

    
1042

    
1043
--
1044
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1045
--
1046

    
1047
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1048
    LANGUAGE sql STABLE
1049
    AS $$
1050
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1051
$$;
1052

    
1053

    
1054
--
1055
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1056
--
1057

    
1058
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1059
    LANGUAGE sql IMMUTABLE
1060
    AS $_$
1061
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1062
$_$;
1063

    
1064

    
1065
--
1066
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1067
--
1068

    
1069
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1070
    LANGUAGE sql IMMUTABLE
1071
    AS $_$
1072
SELECT util.raise('NOTICE', 'returns: '
1073
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
1074
SELECT $1;
1075
$_$;
1076

    
1077

    
1078
--
1079
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1080
--
1081

    
1082
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1083
    LANGUAGE sql IMMUTABLE
1084
    AS $_$
1085
/* newline before so the query starts at the beginning of the line.
1086
newline after to visually separate queries from one another. */
1087
SELECT util.raise('NOTICE', $$
1088
$$||util.runnable_sql($1)||$$
1089
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1090
$_$;
1091

    
1092

    
1093
--
1094
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1095
--
1096

    
1097
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1098
    LANGUAGE sql STABLE
1099
    AS $_$
1100
SELECT util.eval2set($$
1101
SELECT col
1102
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1103
LEFT JOIN $$||$2||$$ ON "to" = col
1104
WHERE "from" IS NULL
1105
$$, NULL::text)
1106
$_$;
1107

    
1108

    
1109
--
1110
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1111
--
1112

    
1113
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1114
gets table_''s derived columns (all the columns not in the names table)
1115
';
1116

    
1117

    
1118
--
1119
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1120
--
1121

    
1122
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1123
    LANGUAGE sql
1124
    AS $_$
1125
-- create a diff when the # of copies of a row differs between the tables
1126
SELECT util.to_freq($1);
1127
SELECT util.to_freq($2);
1128
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1129

    
1130
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1131
$_$;
1132

    
1133

    
1134
--
1135
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1136
--
1137

    
1138
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1139
usage:
1140
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1141

    
1142
col_type_null (*required*): NULL::shared_base_type
1143
';
1144

    
1145

    
1146
--
1147
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1148
--
1149

    
1150
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
1151
    LANGUAGE plpgsql
1152
    SET search_path TO pg_temp
1153
    AS $_$
1154
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1155
changes of search_path (schema elements are bound at inline time rather than
1156
runtime) */
1157
/* function option search_path is needed to limit the effects of
1158
`SET LOCAL search_path` to the current function */
1159
BEGIN
1160
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1161
	
1162
	PERFORM util.mk_keys_func(pg_typeof($3));
1163
	RETURN QUERY
1164
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1165
$$/* need to explicitly cast each side to the return type because this does not
1166
happen automatically even when an implicit cast is available */
1167
  left_::$$||util.typeof($3)||$$
1168
, right_::$$||util.typeof($3)
1169
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1170
the *same* base type, *even though* this is optional when using a custom %== */
1171
, util._if($4, $$true/*= CROSS JOIN*/$$,
1172
$$ left_::$$||util.typeof($3)||$$
1173
%== right_::$$||util.typeof($3)||$$
1174
	-- refer to EXPLAIN output for expansion of %==$$
1175
)
1176
,     $$         left_::$$||util.typeof($3)||$$
1177
IS DISTINCT FROM right_::$$||util.typeof($3)
1178
), $3)
1179
	;
1180
END;
1181
$_$;
1182

    
1183

    
1184
--
1185
-- 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: -
1186
--
1187

    
1188
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1189
col_type_null (*required*): NULL::col_type
1190
single_row: whether the tables consist of a single row, which should be
1191
	displayed side-by-side
1192

    
1193
to match up rows using a subset of the columns, create a custom keys() function
1194
which returns this subset as a record:
1195
-- note that OUT parameters for the returned fields are *not* needed
1196
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1197
  RETURNS record AS
1198
$BODY$
1199
SELECT ($1.key_field_0, $1.key_field_1)
1200
$BODY$
1201
  LANGUAGE sql IMMUTABLE
1202
  COST 100;
1203

    
1204

    
1205
to run EXPLAIN on the FULL JOIN query:
1206
# run this function
1207
# look for a NOTICE containing the expanded query that it ran
1208
# run EXPLAIN on this expanded query
1209
';
1210

    
1211

    
1212
--
1213
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1214
--
1215

    
1216
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
1217
    LANGUAGE sql
1218
    AS $_$
1219
SELECT * FROM util.diff($1::text, $2::text, $3,
1220
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1221
$_$;
1222

    
1223

    
1224
--
1225
-- 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: -
1226
--
1227

    
1228
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1229
helper function used by diff(regclass, regclass)
1230

    
1231
usage:
1232
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1233

    
1234
col_type_null (*required*): NULL::shared_base_type
1235
';
1236

    
1237

    
1238
--
1239
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1240
--
1241

    
1242
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1243
    LANGUAGE sql
1244
    AS $_$
1245
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1246
$_$;
1247

    
1248

    
1249
--
1250
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1251
--
1252

    
1253
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1254
idempotent
1255
';
1256

    
1257

    
1258
--
1259
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1260
--
1261

    
1262
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1263
    LANGUAGE sql
1264
    AS $_$
1265
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1266
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1267
$_$;
1268

    
1269

    
1270
--
1271
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1272
--
1273

    
1274
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1275
idempotent
1276
';
1277

    
1278

    
1279
--
1280
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1281
--
1282

    
1283
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1284
    LANGUAGE sql
1285
    AS $_$
1286
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1287
SELECT NULL::void; -- don't fold away functions called in previous query
1288
$_$;
1289

    
1290

    
1291
--
1292
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1293
--
1294

    
1295
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1296
idempotent
1297
';
1298

    
1299

    
1300
--
1301
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1302
--
1303

    
1304
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1305
    LANGUAGE sql
1306
    AS $_$
1307
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1308
included in the debug SQL */
1309
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1310
$_$;
1311

    
1312

    
1313
--
1314
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1315
--
1316

    
1317
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1318
    LANGUAGE sql
1319
    AS $_$
1320
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1321
||util._if($3, $$ CASCADE$$, ''::text))
1322
$_$;
1323

    
1324

    
1325
--
1326
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1327
--
1328

    
1329
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1330
idempotent
1331
';
1332

    
1333

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

    
1338
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1339
    LANGUAGE sql
1340
    AS $_$
1341
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1342
$_$;
1343

    
1344

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

    
1349
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1350
    LANGUAGE sql
1351
    AS $_$
1352
SELECT util.debug_print_func_call(util.quote_func_call(
1353
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1354
util.quote_typed($3)))
1355
;
1356
SELECT util.drop_relation(relation, $3)
1357
FROM util.show_relations_like($1, $2) relation
1358
;
1359
SELECT NULL::void; -- don't fold away functions called in previous query
1360
$_$;
1361

    
1362

    
1363
--
1364
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1365
--
1366

    
1367
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1368
    LANGUAGE sql
1369
    AS $_$
1370
SELECT util.drop_relation('TABLE', $1, $2)
1371
$_$;
1372

    
1373

    
1374
--
1375
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1376
--
1377

    
1378
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1379
idempotent
1380
';
1381

    
1382

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

    
1387
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1388
    LANGUAGE sql
1389
    AS $_$
1390
SELECT util.drop_relation('VIEW', $1, $2)
1391
$_$;
1392

    
1393

    
1394
--
1395
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1396
--
1397

    
1398
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1399
idempotent
1400
';
1401

    
1402

    
1403
--
1404
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1405
--
1406

    
1407
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1408
    LANGUAGE sql IMMUTABLE
1409
    AS $_$
1410
SELECT util.array_fill($1, 0)
1411
$_$;
1412

    
1413

    
1414
--
1415
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1416
--
1417

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

    
1422

    
1423
--
1424
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1425
--
1426

    
1427
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1428
    LANGUAGE sql IMMUTABLE
1429
    AS $_$
1430
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1431
$_$;
1432

    
1433

    
1434
--
1435
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1436
--
1437

    
1438
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1439
    LANGUAGE sql IMMUTABLE
1440
    AS $_$
1441
SELECT regexp_replace($2, '("?)$', $1||'\1')
1442
$_$;
1443

    
1444

    
1445
--
1446
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1447
--
1448

    
1449
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1450
    LANGUAGE plpgsql
1451
    AS $$
1452
BEGIN
1453
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1454
	EXECUTE sql;
1455
END;
1456
$$;
1457

    
1458

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

    
1463
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1464
    LANGUAGE plpgsql
1465
    AS $$
1466
BEGIN
1467
	PERFORM util.debug_print_sql(sql);
1468
	RETURN QUERY EXECUTE sql;
1469
END;
1470
$$;
1471

    
1472

    
1473
--
1474
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1475
--
1476

    
1477
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1478
col_type_null (*required*): NULL::col_type
1479
';
1480

    
1481

    
1482
--
1483
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1484
--
1485

    
1486
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1487
    LANGUAGE plpgsql
1488
    AS $$
1489
BEGIN
1490
	PERFORM util.debug_print_sql(sql);
1491
	RETURN QUERY EXECUTE sql;
1492
END;
1493
$$;
1494

    
1495

    
1496
--
1497
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1498
--
1499

    
1500
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1501
    LANGUAGE plpgsql
1502
    AS $$
1503
BEGIN
1504
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1505
	RETURN QUERY EXECUTE sql;
1506
END;
1507
$$;
1508

    
1509

    
1510
--
1511
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1512
--
1513

    
1514
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1515
    LANGUAGE plpgsql STABLE
1516
    AS $$
1517
DECLARE
1518
	ret_val ret_type_null%TYPE;
1519
BEGIN
1520
	PERFORM util.debug_print_sql(sql);
1521
	EXECUTE sql INTO STRICT ret_val;
1522
	RETURN ret_val;
1523
END;
1524
$$;
1525

    
1526

    
1527
--
1528
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1529
--
1530

    
1531
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1532
ret_type_null: NULL::ret_type
1533
';
1534

    
1535

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

    
1540
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1541
    LANGUAGE sql
1542
    AS $_$
1543
SELECT util.eval2val($$SELECT $$||$1, $2)
1544
$_$;
1545

    
1546

    
1547
--
1548
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1549
--
1550

    
1551
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1552
ret_type_null: NULL::ret_type
1553
';
1554

    
1555

    
1556
--
1557
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1558
--
1559

    
1560
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1561
    LANGUAGE sql
1562
    AS $_$
1563
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1564
$_$;
1565

    
1566

    
1567
--
1568
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1569
--
1570

    
1571
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1572
sql: can be NULL, which will be passed through
1573
ret_type_null: NULL::ret_type
1574
';
1575

    
1576

    
1577
--
1578
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1579
--
1580

    
1581
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1582
    LANGUAGE sql STABLE
1583
    AS $_$
1584
SELECT col_name
1585
FROM unnest($2) s (col_name)
1586
WHERE util.col_exists(($1, col_name))
1587
$_$;
1588

    
1589

    
1590
--
1591
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1592
--
1593

    
1594
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1595
    LANGUAGE sql
1596
    AS $_$
1597
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1598
$_$;
1599

    
1600

    
1601
--
1602
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1603
--
1604

    
1605
CREATE FUNCTION explain2notice(sql text) RETURNS void
1606
    LANGUAGE sql
1607
    AS $_$
1608
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1609
$_$;
1610

    
1611

    
1612
--
1613
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1614
--
1615

    
1616
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1617
    LANGUAGE sql
1618
    AS $_$
1619
-- newline before and after to visually separate it from other debug info
1620
SELECT COALESCE($$
1621
EXPLAIN:
1622
$$||util.fold_explain_msg(util.explain2str($1))||$$
1623
$$, '')
1624
$_$;
1625

    
1626

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

    
1631
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1632
    LANGUAGE sql
1633
    AS $_$
1634
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1635
$_$;
1636

    
1637

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

    
1642
CREATE FUNCTION explain2str(sql text) RETURNS text
1643
    LANGUAGE sql
1644
    AS $_$
1645
SELECT util.join_strs(explain, $$
1646
$$) FROM util.explain($1)
1647
$_$;
1648

    
1649

    
1650
SET default_tablespace = '';
1651

    
1652
SET default_with_oids = false;
1653

    
1654
--
1655
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1656
--
1657

    
1658
CREATE TABLE explain (
1659
    line text NOT NULL
1660
);
1661

    
1662

    
1663
--
1664
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1665
--
1666

    
1667
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1668
    LANGUAGE sql
1669
    AS $_$
1670
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1671
$$||quote_nullable($1)||$$
1672
)$$)
1673
$_$;
1674

    
1675

    
1676
--
1677
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1678
--
1679

    
1680
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1681
usage:
1682
PERFORM util.explain2table($$
1683
query
1684
$$);
1685
';
1686

    
1687

    
1688
--
1689
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1690
--
1691

    
1692
CREATE FUNCTION first_word(str text) RETURNS text
1693
    LANGUAGE sql IMMUTABLE
1694
    AS $_$
1695
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1696
$_$;
1697

    
1698

    
1699
--
1700
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1701
--
1702

    
1703
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1704
    LANGUAGE sql IMMUTABLE
1705
    AS $_$
1706
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1707
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1708
) END
1709
$_$;
1710

    
1711

    
1712
--
1713
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1714
--
1715

    
1716
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1717
ensures that an array will always have proper non-NULL dimensions
1718
';
1719

    
1720

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

    
1725
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1726
    LANGUAGE sql IMMUTABLE
1727
    AS $_$
1728
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1729
$_$;
1730

    
1731

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

    
1736
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1737
    LANGUAGE plpgsql
1738
    AS $_$
1739
DECLARE
1740
	PG_EXCEPTION_DETAIL text;
1741
	recreate_users_cmd text = util.save_drop_views(users);
1742
BEGIN
1743
	PERFORM util.eval(cmd);
1744
	PERFORM util.eval(recreate_users_cmd);
1745
EXCEPTION
1746
WHEN dependent_objects_still_exist THEN
1747
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1748
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1749
	users = array(SELECT * FROM util.regexp_matches_group(
1750
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1751
	IF util.is_empty(users) THEN RAISE; END IF;
1752
	PERFORM util.force_recreate(cmd, users);
1753
END;
1754
$_$;
1755

    
1756

    
1757
--
1758
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1759
--
1760

    
1761
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1762
idempotent
1763

    
1764
users: not necessary to provide this because it will be autopopulated
1765
';
1766

    
1767

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

    
1772
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1773
    LANGUAGE plpgsql STRICT
1774
    AS $_$
1775
DECLARE
1776
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1777
$$||query;
1778
BEGIN
1779
	EXECUTE mk_view;
1780
EXCEPTION
1781
WHEN invalid_table_definition THEN
1782
	IF SQLERRM = 'cannot drop columns from view'
1783
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1784
	THEN
1785
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1786
		EXECUTE mk_view;
1787
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1788
	END IF;
1789
END;
1790
$_$;
1791

    
1792

    
1793
--
1794
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1795
--
1796

    
1797
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1798
idempotent
1799
';
1800

    
1801

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

    
1806
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1807
    LANGUAGE sql STABLE
1808
    AS $_$
1809
SELECT util.eval2val(
1810
$$SELECT NOT EXISTS( -- there is no row that is != 1
1811
	SELECT NULL
1812
	FROM $$||$1||$$
1813
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1814
	LIMIT 1
1815
)
1816
$$, NULL::boolean)
1817
$_$;
1818

    
1819

    
1820
--
1821
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1822
--
1823

    
1824
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1825
    LANGUAGE sql STABLE
1826
    AS $_$
1827
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1828
$_$;
1829

    
1830

    
1831
--
1832
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1833
--
1834

    
1835
CREATE FUNCTION grants_users() RETURNS SETOF text
1836
    LANGUAGE sql IMMUTABLE
1837
    AS $$
1838
VALUES ('bien_read'), ('public_')
1839
$$;
1840

    
1841

    
1842
--
1843
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1844
--
1845

    
1846
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1847
    LANGUAGE sql IMMUTABLE
1848
    AS $_$
1849
SELECT substring($2 for length($1)) = $1
1850
$_$;
1851

    
1852

    
1853
--
1854
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856

    
1857
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1858
    LANGUAGE sql STABLE
1859
    AS $_$
1860
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1861
$_$;
1862

    
1863

    
1864
--
1865
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1866
--
1867

    
1868
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1869
    LANGUAGE sql IMMUTABLE
1870
    AS $_$
1871
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1872
$_$;
1873

    
1874

    
1875
--
1876
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1877
--
1878

    
1879
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1880
avoids repeating the same value for each key
1881
';
1882

    
1883

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

    
1888
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1889
    LANGUAGE sql IMMUTABLE
1890
    AS $_$
1891
SELECT COALESCE($1, $2)
1892
$_$;
1893

    
1894

    
1895
--
1896
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1897
--
1898

    
1899
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1900
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1901
';
1902

    
1903

    
1904
--
1905
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1906
--
1907

    
1908
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1909
    LANGUAGE sql
1910
    AS $_$
1911
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1912
$_$;
1913

    
1914

    
1915
--
1916
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1917
--
1918

    
1919
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1920
    LANGUAGE sql STABLE
1921
    AS $_$
1922
SELECT COALESCE(util.col_comment($1) LIKE '
1923
constant
1924
%', false)
1925
$_$;
1926

    
1927

    
1928
--
1929
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1930
--
1931

    
1932
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1933
    LANGUAGE sql IMMUTABLE
1934
    AS $_$
1935
SELECT util.array_length($1) = 0
1936
$_$;
1937

    
1938

    
1939
--
1940
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1941
--
1942

    
1943
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1944
    LANGUAGE sql IMMUTABLE
1945
    AS $_$
1946
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1947
$_$;
1948

    
1949

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

    
1954
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1955
    LANGUAGE sql IMMUTABLE
1956
    AS $_$
1957
SELECT upper(util.first_word($1)) = ANY(
1958
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1959
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1960
)
1961
$_$;
1962

    
1963

    
1964
--
1965
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1966
--
1967

    
1968
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1969
    LANGUAGE sql IMMUTABLE
1970
    AS $_$
1971
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1972
$_$;
1973

    
1974

    
1975
--
1976
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1977
--
1978

    
1979
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1980
    LANGUAGE sql IMMUTABLE
1981
    AS $_$
1982
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1983
$_$;
1984

    
1985

    
1986
--
1987
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1988
--
1989

    
1990
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1991
    LANGUAGE sql IMMUTABLE
1992
    AS $_$
1993
SELECT upper(util.first_word($1)) = 'SET'
1994
$_$;
1995

    
1996

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

    
2001
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2002
    LANGUAGE sql STABLE
2003
    AS $_$
2004
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2005
$_$;
2006

    
2007

    
2008
--
2009
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2010
--
2011

    
2012
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2013
    LANGUAGE sql STABLE
2014
    AS $_$
2015
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2016
$_$;
2017

    
2018

    
2019
--
2020
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2021
--
2022

    
2023
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2024
    LANGUAGE sql IMMUTABLE STRICT
2025
    AS $_$
2026
SELECT $1 || $3 || $2
2027
$_$;
2028

    
2029

    
2030
--
2031
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2032
--
2033

    
2034
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2035
must be declared STRICT to use the special handling of STRICT aggregating functions
2036
';
2037

    
2038

    
2039
--
2040
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2041
--
2042

    
2043
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2044
    LANGUAGE sql IMMUTABLE
2045
    AS $_$
2046
SELECT $1 -- compare on the entire value
2047
$_$;
2048

    
2049

    
2050
--
2051
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2052
--
2053

    
2054
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2055
    LANGUAGE sql IMMUTABLE
2056
    AS $_$
2057
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2058
$_$;
2059

    
2060

    
2061
--
2062
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2063
--
2064

    
2065
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2066
    LANGUAGE sql IMMUTABLE
2067
    AS $_$
2068
SELECT ltrim($1, $$
2069
$$)
2070
$_$;
2071

    
2072

    
2073
--
2074
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2075
--
2076

    
2077
CREATE FUNCTION map_filter_insert() RETURNS trigger
2078
    LANGUAGE plpgsql
2079
    AS $$
2080
BEGIN
2081
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2082
	RETURN new;
2083
END;
2084
$$;
2085

    
2086

    
2087
--
2088
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2089
--
2090

    
2091
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2092
    LANGUAGE plpgsql STABLE STRICT
2093
    AS $_$
2094
DECLARE
2095
    value text;
2096
BEGIN
2097
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2098
        INTO value USING key;
2099
    RETURN value;
2100
END;
2101
$_$;
2102

    
2103

    
2104
--
2105
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2106
--
2107

    
2108
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2109
    LANGUAGE sql IMMUTABLE
2110
    AS $_$
2111
SELECT util._map(util.nulls_map($1), $2)
2112
$_$;
2113

    
2114

    
2115
--
2116
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2117
--
2118

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

    
2122
[1] inlining of function calls, which is different from constant folding
2123
[2] _map()''s profiling query
2124
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2125
and map_nulls()''s profiling query
2126
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2127
both take ~920 ms.
2128
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.
2129
';
2130

    
2131

    
2132
--
2133
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2134
--
2135

    
2136
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2137
    LANGUAGE plpgsql STABLE STRICT
2138
    AS $_$
2139
BEGIN
2140
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2141
END;
2142
$_$;
2143

    
2144

    
2145
--
2146
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2147
--
2148

    
2149
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2150
    LANGUAGE sql
2151
    AS $_$
2152
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2153
$$||util.ltrim_nl($2));
2154
-- make sure the created table has the correct estimated row count
2155
SELECT util.analyze_($1);
2156

    
2157
SELECT util.append_comment($1, '
2158
contents generated from:
2159
'||util.ltrim_nl($2)||';
2160
');
2161
$_$;
2162

    
2163

    
2164
--
2165
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2166
--
2167

    
2168
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2169
idempotent
2170
';
2171

    
2172

    
2173
--
2174
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2175
--
2176

    
2177
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2178
    LANGUAGE sql
2179
    AS $_$
2180
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2181
$_$;
2182

    
2183

    
2184
--
2185
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2186
--
2187

    
2188
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2189
idempotent
2190
';
2191

    
2192

    
2193
--
2194
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2195
--
2196

    
2197
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2198
    LANGUAGE sql
2199
    AS $_$
2200
SELECT util.create_if_not_exists($$
2201
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2202
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2203
||quote_literal($2)||$$;
2204
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2205
constant
2206
';
2207
$$)
2208
$_$;
2209

    
2210

    
2211
--
2212
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2213
--
2214

    
2215
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2216
idempotent
2217
';
2218

    
2219

    
2220
--
2221
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2222
--
2223

    
2224
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2225
    LANGUAGE plpgsql STRICT
2226
    AS $_$
2227
DECLARE
2228
    type regtype = util.typeof(expr, col.table_::text::regtype);
2229
    col_name_sql text = quote_ident(col.name);
2230
BEGIN
2231
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2232
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2233
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2234
$$||expr||$$;
2235
$$);
2236
END;
2237
$_$;
2238

    
2239

    
2240
--
2241
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2242
--
2243

    
2244
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2245
idempotent
2246
';
2247

    
2248

    
2249
--
2250
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2251
--
2252

    
2253
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
2254
    LANGUAGE sql IMMUTABLE
2255
    AS $_$
2256
SELECT
2257
$$SELECT
2258
$$||$3||$$
2259
FROM      $$||$1||$$ left_
2260
FULL JOIN $$||$2||$$ right_
2261
ON $$||$4||$$
2262
WHERE $$||$5||$$
2263
ORDER BY left_, right_
2264
$$
2265
$_$;
2266

    
2267

    
2268
--
2269
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2270
--
2271

    
2272
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2273
    LANGUAGE sql
2274
    AS $_$
2275
-- keys()
2276
SELECT util.mk_keys_func($1, ARRAY(
2277
SELECT col FROM util.typed_cols($1) col
2278
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2279
));
2280

    
2281
-- values_()
2282
SELECT util.mk_keys_func($1, COALESCE(
2283
	NULLIF(ARRAY(
2284
	SELECT col FROM util.typed_cols($1) col
2285
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2286
	), ARRAY[]::util.col_cast[])
2287
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2288
, 'values_');
2289
$_$;
2290

    
2291

    
2292
--
2293
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2294
--
2295

    
2296
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2297
    LANGUAGE sql
2298
    AS $_$
2299
SELECT util.create_if_not_exists($$
2300
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2301
($$||util.mk_typed_cols_list($2)||$$);
2302
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2303
autogenerated
2304
';
2305
$$);
2306

    
2307
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2308
$_$;
2309

    
2310

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

    
2315
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2316
    LANGUAGE sql
2317
    AS $_$
2318
SELECT util.create_if_not_exists($$
2319
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2320
||util.qual_name($1)||$$)
2321
  RETURNS $$||util.qual_name($2)||$$ AS
2322
$BODY1$
2323
SELECT ROW($$||
2324
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2325
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2326
$BODY1$
2327
  LANGUAGE sql IMMUTABLE
2328
  COST 100;
2329
$$);
2330
$_$;
2331

    
2332

    
2333
--
2334
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2335
--
2336

    
2337
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2338
    LANGUAGE sql
2339
    AS $_$
2340
SELECT util.create_if_not_exists($$
2341
CREATE TABLE $$||$1||$$
2342
(
2343
    LIKE util.map INCLUDING ALL
2344
);
2345

    
2346
CREATE TRIGGER map_filter_insert
2347
  BEFORE INSERT
2348
  ON $$||$1||$$
2349
  FOR EACH ROW
2350
  EXECUTE PROCEDURE util.map_filter_insert();
2351
$$)
2352
$_$;
2353

    
2354

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

    
2359
CREATE FUNCTION mk_not_null(text) RETURNS text
2360
    LANGUAGE sql IMMUTABLE
2361
    AS $_$
2362
SELECT COALESCE($1, '<NULL>')
2363
$_$;
2364

    
2365

    
2366
--
2367
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2368
--
2369

    
2370
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2371
    LANGUAGE sql IMMUTABLE
2372
    AS $_$
2373
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2374
util.qual_name((unnest).type), ''), '')
2375
FROM unnest($1)
2376
$_$;
2377

    
2378

    
2379
--
2380
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2381
--
2382

    
2383
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2384
    LANGUAGE sql IMMUTABLE
2385
    AS $_$
2386
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2387
$_$;
2388

    
2389

    
2390
--
2391
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2392
--
2393

    
2394
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2395
auto-appends util to the search_path to enable use of util operators
2396
';
2397

    
2398

    
2399
--
2400
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2401
--
2402

    
2403
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2404
    LANGUAGE sql IMMUTABLE
2405
    AS $_$
2406
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2407
$_$;
2408

    
2409

    
2410
--
2411
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2412
--
2413

    
2414
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2415
    LANGUAGE sql IMMUTABLE
2416
    AS $_$
2417
/* debug_print_return_value() needed because this function is used with EXECUTE
2418
rather than util.eval() (in order to affect the calling function), so the
2419
search_path would not otherwise be printed */
2420
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2421
||$$ search_path TO $$||$1
2422
$_$;
2423

    
2424

    
2425
--
2426
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2427
--
2428

    
2429
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2430
    LANGUAGE sql
2431
    AS $_$
2432
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2433
$_$;
2434

    
2435

    
2436
--
2437
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2438
--
2439

    
2440
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2441
idempotent
2442
';
2443

    
2444

    
2445
--
2446
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2447
--
2448

    
2449
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2450
    LANGUAGE plpgsql STRICT
2451
    AS $_$
2452
DECLARE
2453
	view_qual_name text = util.qual_name(view_);
2454
BEGIN
2455
	EXECUTE $$
2456
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2457
  RETURNS SETOF $$||view_||$$ AS
2458
$BODY1$
2459
SELECT * FROM $$||view_qual_name||$$
2460
ORDER BY sort_col
2461
LIMIT $1 OFFSET $2
2462
$BODY1$
2463
  LANGUAGE sql STABLE
2464
  COST 100
2465
  ROWS 1000
2466
$$;
2467
	
2468
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2469
END;
2470
$_$;
2471

    
2472

    
2473
--
2474
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2475
--
2476

    
2477
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2478
    LANGUAGE plpgsql STRICT
2479
    AS $_$
2480
DECLARE
2481
	view_qual_name text = util.qual_name(view_);
2482
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2483
BEGIN
2484
	EXECUTE $$
2485
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2486
  RETURNS integer AS
2487
$BODY1$
2488
SELECT $$||quote_ident(row_num_col)||$$
2489
FROM $$||view_qual_name||$$
2490
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2491
LIMIT 1
2492
$BODY1$
2493
  LANGUAGE sql STABLE
2494
  COST 100;
2495
$$;
2496
	
2497
	EXECUTE $$
2498
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2499
  RETURNS SETOF $$||view_||$$ AS
2500
$BODY1$
2501
SELECT * FROM $$||view_qual_name||$$
2502
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2503
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2504
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2505
ORDER BY $$||quote_ident(row_num_col)||$$
2506
$BODY1$
2507
  LANGUAGE sql STABLE
2508
  COST 100
2509
  ROWS 1000
2510
$$;
2511
	
2512
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2513
END;
2514
$_$;
2515

    
2516

    
2517
--
2518
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2519
--
2520

    
2521
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2522
    LANGUAGE plpgsql STRICT
2523
    AS $_$
2524
DECLARE
2525
	view_qual_name text = util.qual_name(view_);
2526
BEGIN
2527
	EXECUTE $$
2528
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2529
  RETURNS SETOF $$||view_||$$
2530
  SET enable_sort TO 'off'
2531
  AS
2532
$BODY1$
2533
SELECT * FROM $$||view_qual_name||$$($2, $3)
2534
$BODY1$
2535
  LANGUAGE sql STABLE
2536
  COST 100
2537
  ROWS 1000
2538
;
2539
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2540
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2541
If you want to run EXPLAIN and get expanded output, use the regular subset
2542
function instead. (When a config param is set on a function, EXPLAIN produces
2543
just a function scan.)
2544
';
2545
$$;
2546
END;
2547
$_$;
2548

    
2549

    
2550
--
2551
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2552
--
2553

    
2554
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2555
creates subset function which turns off enable_sort
2556
';
2557

    
2558

    
2559
--
2560
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2561
--
2562

    
2563
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2564
    LANGUAGE sql IMMUTABLE
2565
    AS $_$
2566
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2567
util.qual_name((unnest).type), ', '), '')
2568
FROM unnest($1)
2569
$_$;
2570

    
2571

    
2572
--
2573
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2574
--
2575

    
2576
CREATE FUNCTION name(table_ regclass) RETURNS text
2577
    LANGUAGE sql STABLE
2578
    AS $_$
2579
SELECT relname::text FROM pg_class WHERE oid = $1
2580
$_$;
2581

    
2582

    
2583
--
2584
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2585
--
2586

    
2587
CREATE FUNCTION name(type regtype) RETURNS text
2588
    LANGUAGE sql STABLE
2589
    AS $_$
2590
SELECT typname::text FROM pg_type WHERE oid = $1
2591
$_$;
2592

    
2593

    
2594
--
2595
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2596
--
2597

    
2598
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2599
    LANGUAGE sql IMMUTABLE
2600
    AS $_$
2601
SELECT octet_length($1) >= util.namedatalen() - $2
2602
$_$;
2603

    
2604

    
2605
--
2606
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2607
--
2608

    
2609
CREATE FUNCTION namedatalen() RETURNS integer
2610
    LANGUAGE sql IMMUTABLE
2611
    AS $$
2612
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2613
$$;
2614

    
2615

    
2616
--
2617
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2618
--
2619

    
2620
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2621
    LANGUAGE sql IMMUTABLE
2622
    AS $_$
2623
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2624
$_$;
2625

    
2626

    
2627
--
2628
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2629
--
2630

    
2631
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2632
    LANGUAGE sql IMMUTABLE
2633
    AS $_$
2634
SELECT $1 IS NOT NULL
2635
$_$;
2636

    
2637

    
2638
--
2639
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2640
--
2641

    
2642
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2643
    LANGUAGE sql IMMUTABLE
2644
    AS $_$
2645
SELECT util.hstore($1, NULL) || '*=>*'
2646
$_$;
2647

    
2648

    
2649
--
2650
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2651
--
2652

    
2653
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2654
for use with _map()
2655
';
2656

    
2657

    
2658
--
2659
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2660
--
2661

    
2662
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2663
    LANGUAGE sql IMMUTABLE
2664
    AS $_$
2665
SELECT $2 + COALESCE($1, 0)
2666
$_$;
2667

    
2668

    
2669
--
2670
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2671
--
2672

    
2673
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2674
    LANGUAGE sql STABLE
2675
    AS $_$
2676
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2677
$_$;
2678

    
2679

    
2680
--
2681
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2682
--
2683

    
2684
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2685
    LANGUAGE sql
2686
    AS $_$
2687
SELECT util.eval($$INSERT INTO $$||$1||$$
2688
$$||util.ltrim_nl($2));
2689
-- make sure the created table has the correct estimated row count
2690
SELECT util.analyze_($1);
2691
$_$;
2692

    
2693

    
2694
--
2695
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2696
--
2697

    
2698
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2699
    LANGUAGE sql IMMUTABLE
2700
    AS $_$
2701
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2702
$_$;
2703

    
2704

    
2705
--
2706
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2707
--
2708

    
2709
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2710
    LANGUAGE sql
2711
    AS $_$
2712
SELECT util.set_comment($1, concat($2, util.comment($1)))
2713
$_$;
2714

    
2715

    
2716
--
2717
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2718
--
2719

    
2720
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2721
comment: must start and end with a newline
2722
';
2723

    
2724

    
2725
--
2726
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2727
--
2728

    
2729
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2730
    LANGUAGE sql IMMUTABLE
2731
    AS $_$
2732
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2733
$_$;
2734

    
2735

    
2736
--
2737
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2738
--
2739

    
2740
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2741
    LANGUAGE sql STABLE
2742
    SET search_path TO pg_temp
2743
    AS $_$
2744
SELECT $1::text
2745
$_$;
2746

    
2747

    
2748
--
2749
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2750
--
2751

    
2752
CREATE FUNCTION qual_name(type regtype) RETURNS text
2753
    LANGUAGE sql STABLE
2754
    SET search_path TO pg_temp
2755
    AS $_$
2756
SELECT $1::text
2757
$_$;
2758

    
2759

    
2760
--
2761
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2762
--
2763

    
2764
COMMENT ON FUNCTION qual_name(type regtype) IS '
2765
a type''s schema-qualified name
2766
';
2767

    
2768

    
2769
--
2770
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2771
--
2772

    
2773
CREATE FUNCTION qual_name(type unknown) RETURNS text
2774
    LANGUAGE sql STABLE
2775
    AS $_$
2776
SELECT util.qual_name($1::text::regtype)
2777
$_$;
2778

    
2779

    
2780
--
2781
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2782
--
2783

    
2784
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2785
    LANGUAGE sql IMMUTABLE
2786
    AS $_$
2787
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2788
$_$;
2789

    
2790

    
2791
--
2792
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2793
--
2794

    
2795
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2796
    LANGUAGE sql IMMUTABLE
2797
    AS $_$
2798
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2799
$_$;
2800

    
2801

    
2802
--
2803
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2804
--
2805

    
2806
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2807
    LANGUAGE sql IMMUTABLE
2808
    AS $_$
2809
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2810
$_$;
2811

    
2812

    
2813
--
2814
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2815
--
2816

    
2817
CREATE FUNCTION raise(type text, msg text) RETURNS void
2818
    LANGUAGE sql IMMUTABLE
2819
    AS $_X$
2820
SELECT util.eval($$
2821
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2822
  RETURNS void AS
2823
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2824
$__BODY1$
2825
BEGIN
2826
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2827
END;
2828
$__BODY1$
2829
  LANGUAGE plpgsql IMMUTABLE
2830
  COST 100;
2831
$$, verbose_ := false);
2832

    
2833
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2834
$_X$;
2835

    
2836

    
2837
--
2838
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2839
--
2840

    
2841
COMMENT ON FUNCTION raise(type text, msg text) IS '
2842
type: a log level from
2843
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2844
or a condition name from
2845
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2846
';
2847

    
2848

    
2849
--
2850
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2851
--
2852

    
2853
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2854
    LANGUAGE sql IMMUTABLE
2855
    AS $_$
2856
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2857
$_$;
2858

    
2859

    
2860
--
2861
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2862
--
2863

    
2864
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2865
    LANGUAGE plpgsql IMMUTABLE STRICT
2866
    AS $$
2867
BEGIN
2868
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2869
END;
2870
$$;
2871

    
2872

    
2873
--
2874
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2875
--
2876

    
2877
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2878
    LANGUAGE sql IMMUTABLE
2879
    AS $_$
2880
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2881
$_$;
2882

    
2883

    
2884
--
2885
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2886
--
2887

    
2888
CREATE FUNCTION regexp_quote(str text) RETURNS text
2889
    LANGUAGE sql IMMUTABLE
2890
    AS $_$
2891
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2892
$_$;
2893

    
2894

    
2895
--
2896
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2897
--
2898

    
2899
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2900
    LANGUAGE sql IMMUTABLE
2901
    AS $_$
2902
SELECT (CASE WHEN right($1, 1) = ')'
2903
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2904
$_$;
2905

    
2906

    
2907
--
2908
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2909
--
2910

    
2911
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2912
    LANGUAGE sql STABLE
2913
    AS $_$
2914
SELECT util.relation_type(util.relation_type_char($1))
2915
$_$;
2916

    
2917

    
2918
--
2919
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2920
--
2921

    
2922
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2923
    LANGUAGE sql IMMUTABLE
2924
    AS $_$
2925
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2926
$_$;
2927

    
2928

    
2929
--
2930
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2931
--
2932

    
2933
CREATE FUNCTION relation_type(type regtype) RETURNS text
2934
    LANGUAGE sql IMMUTABLE
2935
    AS $$
2936
SELECT 'TYPE'::text
2937
$$;
2938

    
2939

    
2940
--
2941
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2942
--
2943

    
2944
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2945
    LANGUAGE sql STABLE
2946
    AS $_$
2947
SELECT relkind FROM pg_class WHERE oid = $1
2948
$_$;
2949

    
2950

    
2951
--
2952
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2953
--
2954

    
2955
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2956
    LANGUAGE sql
2957
    AS $_$
2958
/* can't have in_table/out_table inherit from *each other*, because inheritance
2959
also causes the rows of the parent table to be included in the child table.
2960
instead, they need to inherit from a common, empty table. */
2961
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2962
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2963
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
2964
SELECT util.inherit($2, $4);
2965
SELECT util.inherit($3, $4);
2966

    
2967
SELECT util.rematerialize_query($1, $$
2968
SELECT * FROM util.diff(
2969
  $$||util.quote_typed($2)||$$
2970
, $$||util.quote_typed($3)||$$
2971
, NULL::$$||$4||$$)
2972
$$);
2973

    
2974
/* the table unfortunately cannot be *materialized* in human-readable form,
2975
because this would create column name collisions between the two sides */
2976
SELECT util.prepend_comment($1, '
2977
to view this table in human-readable form (with each side''s tuple column
2978
expanded to its component fields):
2979
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2980

    
2981
to display NULL values that are extra or missing:
2982
SELECT * FROM '||$1||';
2983
');
2984
$_$;
2985

    
2986

    
2987
--
2988
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2989
--
2990

    
2991
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2992
type_table (*required*): table to create as the shared base type
2993
';
2994

    
2995

    
2996
--
2997
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2998
--
2999

    
3000
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3001
    LANGUAGE sql
3002
    AS $_$
3003
SELECT util.drop_table($1);
3004
SELECT util.materialize_query($1, $2);
3005
$_$;
3006

    
3007

    
3008
--
3009
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3010
--
3011

    
3012
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3013
idempotent, but repeats action each time
3014
';
3015

    
3016

    
3017
--
3018
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3019
--
3020

    
3021
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3022
    LANGUAGE sql
3023
    AS $_$
3024
SELECT util.drop_table($1);
3025
SELECT util.materialize_view($1, $2);
3026
$_$;
3027

    
3028

    
3029
--
3030
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3031
--
3032

    
3033
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3034
idempotent, but repeats action each time
3035
';
3036

    
3037

    
3038
--
3039
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3040
--
3041

    
3042
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3043
    LANGUAGE sql
3044
    AS $_$
3045
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3046
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3047
FROM util.col_names($1::text::regtype) f (name);
3048
SELECT NULL::void; -- don't fold away functions called in previous query
3049
$_$;
3050

    
3051

    
3052
--
3053
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3054
--
3055

    
3056
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3057
idempotent
3058
';
3059

    
3060

    
3061
--
3062
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3063
--
3064

    
3065
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3066
    LANGUAGE sql
3067
    AS $_$
3068
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3069
included in the debug SQL */
3070
SELECT util.rename_relation(util.qual_name($1), $2)
3071
$_$;
3072

    
3073

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

    
3078
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3079
    LANGUAGE sql
3080
    AS $_$
3081
/* 'ALTER TABLE can be used with views too'
3082
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3083
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3084
||quote_ident($2))
3085
$_$;
3086

    
3087

    
3088
--
3089
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3090
--
3091

    
3092
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3093
idempotent
3094
';
3095

    
3096

    
3097
--
3098
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3099
--
3100

    
3101
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3102
    LANGUAGE sql IMMUTABLE
3103
    AS $_$
3104
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3105
$_$;
3106

    
3107

    
3108
--
3109
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3110
--
3111

    
3112
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3113
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 
3114
';
3115

    
3116

    
3117
--
3118
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3119
--
3120

    
3121
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3122
    LANGUAGE sql
3123
    AS $_$
3124
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3125
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3126
SELECT util.set_col_names($1, $2);
3127
$_$;
3128

    
3129

    
3130
--
3131
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3132
--
3133

    
3134
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3135
idempotent.
3136
alters the names table, so it will need to be repopulated after running this function.
3137
';
3138

    
3139

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

    
3144
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3145
    LANGUAGE sql
3146
    AS $_$
3147
SELECT util.drop_table($1);
3148
SELECT util.mk_map_table($1);
3149
$_$;
3150

    
3151

    
3152
--
3153
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3154
--
3155

    
3156
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3157
    LANGUAGE sql
3158
    AS $_$
3159
SELECT util.drop_column($1, $2, force := true)
3160
$_$;
3161

    
3162

    
3163
--
3164
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3165
--
3166

    
3167
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3168
    LANGUAGE sql IMMUTABLE
3169
    AS $_$
3170
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3171
$_$;
3172

    
3173

    
3174
--
3175
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3176
--
3177

    
3178
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3179
    LANGUAGE sql IMMUTABLE
3180
    AS $_$
3181
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3182
ELSE util.mk_set_search_path(for_printing := true)||$$;
3183
$$ END)||$1
3184
$_$;
3185

    
3186

    
3187
--
3188
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3189
--
3190

    
3191
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3192
    LANGUAGE plpgsql STRICT
3193
    AS $_$
3194
DECLARE
3195
	result text = NULL;
3196
BEGIN
3197
	BEGIN
3198
		result = util.show_create_view(view_);
3199
		PERFORM util.eval($$DROP VIEW $$||view_);
3200
	EXCEPTION
3201
		WHEN undefined_table THEN NULL;
3202
	END;
3203
	RETURN result;
3204
END;
3205
$_$;
3206

    
3207

    
3208
--
3209
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3210
--
3211

    
3212
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3213
    LANGUAGE sql
3214
    AS $_$
3215
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3216
$_$;
3217

    
3218

    
3219
--
3220
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3221
--
3222

    
3223
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3224
    LANGUAGE sql STABLE
3225
    AS $_$
3226
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3227
$_$;
3228

    
3229

    
3230
--
3231
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3232
--
3233

    
3234
CREATE FUNCTION schema(table_ regclass) RETURNS text
3235
    LANGUAGE sql STABLE
3236
    AS $_$
3237
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3238
$_$;
3239

    
3240

    
3241
--
3242
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3243
--
3244

    
3245
CREATE FUNCTION schema(type regtype) RETURNS text
3246
    LANGUAGE sql STABLE
3247
    AS $_$
3248
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3249
$_$;
3250

    
3251

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

    
3256
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3257
    LANGUAGE sql STABLE
3258
    AS $_$
3259
SELECT util.schema(pg_typeof($1))
3260
$_$;
3261

    
3262

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

    
3267
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3268
    LANGUAGE sql STABLE
3269
    AS $_$
3270
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3271
$_$;
3272

    
3273

    
3274
--
3275
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3276
--
3277

    
3278
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3279
a schema bundle is a group of schemas with a common prefix
3280
';
3281

    
3282

    
3283
--
3284
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3285
--
3286

    
3287
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3288
    LANGUAGE sql
3289
    AS $_$
3290
SELECT util.schema_rename(old_schema,
3291
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3292
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3293
SELECT NULL::void; -- don't fold away functions called in previous query
3294
$_$;
3295

    
3296

    
3297
--
3298
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3299
--
3300

    
3301
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3302
    LANGUAGE plpgsql
3303
    AS $$
3304
BEGIN
3305
	-- don't schema_bundle_rm() the schema_bundle to keep!
3306
	IF replace = with_ THEN RETURN; END IF;
3307
	
3308
	PERFORM util.schema_bundle_rm(replace);
3309
	PERFORM util.schema_bundle_rename(with_, replace);
3310
END;
3311
$$;
3312

    
3313

    
3314
--
3315
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3316
--
3317

    
3318
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3319
    LANGUAGE sql
3320
    AS $_$
3321
SELECT util.schema_rm(schema)
3322
FROM util.schema_bundle_get_schemas($1) f (schema);
3323
SELECT NULL::void; -- don't fold away functions called in previous query
3324
$_$;
3325

    
3326

    
3327
--
3328
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3329
--
3330

    
3331
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3332
    LANGUAGE sql STABLE
3333
    AS $_$
3334
SELECT quote_ident(util.schema($1))
3335
$_$;
3336

    
3337

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

    
3342
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3343
    LANGUAGE sql IMMUTABLE
3344
    AS $_$
3345
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3346
$_$;
3347

    
3348

    
3349
--
3350
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3351
--
3352

    
3353
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3354
    LANGUAGE sql STABLE
3355
    AS $_$
3356
SELECT oid FROM pg_namespace WHERE nspname = $1
3357
$_$;
3358

    
3359

    
3360
--
3361
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3362
--
3363

    
3364
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3365
    LANGUAGE sql IMMUTABLE
3366
    AS $_$
3367
SELECT util.schema_regexp(schema_anchor := $1)
3368
$_$;
3369

    
3370

    
3371
--
3372
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3373
--
3374

    
3375
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3376
    LANGUAGE sql IMMUTABLE
3377
    AS $_$
3378
SELECT util.str_equality_regexp(util.schema($1))
3379
$_$;
3380

    
3381

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

    
3386
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3387
    LANGUAGE sql
3388
    AS $_$
3389
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3390
$_$;
3391

    
3392

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

    
3397
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3398
    LANGUAGE plpgsql
3399
    AS $$
3400
BEGIN
3401
	-- don't schema_rm() the schema to keep!
3402
	IF replace = with_ THEN RETURN; END IF;
3403
	
3404
	PERFORM util.schema_rm(replace);
3405
	PERFORM util.schema_rename(with_, replace);
3406
END;
3407
$$;
3408

    
3409

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

    
3414
CREATE FUNCTION schema_rm(schema text) RETURNS void
3415
    LANGUAGE sql
3416
    AS $_$
3417
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3418
$_$;
3419

    
3420

    
3421
--
3422
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3423
--
3424

    
3425
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3426
    LANGUAGE sql
3427
    AS $_$
3428
SELECT util.eval(
3429
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3430
$_$;
3431

    
3432

    
3433
--
3434
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3435
--
3436

    
3437
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3438
    LANGUAGE plpgsql STRICT
3439
    AS $_$
3440
DECLARE
3441
    old text[] = ARRAY(SELECT util.col_names(table_));
3442
    new text[] = ARRAY(SELECT util.map_values(names));
3443
BEGIN
3444
    old = old[1:array_length(new, 1)]; -- truncate to same length
3445
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3446
||$$ TO $$||quote_ident(value))
3447
    FROM each(hstore(old, new))
3448
    WHERE value != key -- not same name
3449
    ;
3450
END;
3451
$_$;
3452

    
3453

    
3454
--
3455
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3456
--
3457

    
3458
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3459
idempotent
3460
';
3461

    
3462

    
3463
--
3464
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3465
--
3466

    
3467
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3468
    LANGUAGE plpgsql STRICT
3469
    AS $_$
3470
DECLARE
3471
	row_ util.map;
3472
BEGIN
3473
	-- rename any metadata cols rather than re-adding them with new names
3474
	BEGIN
3475
		PERFORM util.set_col_names(table_, names);
3476
	EXCEPTION
3477
		WHEN array_subscript_error THEN -- selective suppress
3478
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3479
				-- metadata cols not yet added
3480
			ELSE RAISE;
3481
			END IF;
3482
	END;
3483
	
3484
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3485
	LOOP
3486
		PERFORM util.mk_const_col((table_, row_."to"),
3487
			substring(row_."from" from 2));
3488
	END LOOP;
3489
	
3490
	PERFORM util.set_col_names(table_, names);
3491
END;
3492
$_$;
3493

    
3494

    
3495
--
3496
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3497
--
3498

    
3499
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3500
idempotent.
3501
the metadata mappings must be *last* in the names table.
3502
';
3503

    
3504

    
3505
--
3506
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3507
--
3508

    
3509
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3510
    LANGUAGE sql
3511
    AS $_$
3512
SELECT util.eval(COALESCE(
3513
$$ALTER TABLE $$||$1||$$
3514
$$||(
3515
	SELECT
3516
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3517
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
3518
, $$)
3519
	FROM
3520
	(
3521
		SELECT
3522
		  quote_ident(col_name) AS col_name_sql
3523
		, util.col_type(($1, col_name)) AS curr_type
3524
		, type AS target_type
3525
		FROM unnest($2)
3526
	) s
3527
	WHERE curr_type != target_type
3528
), ''))
3529
$_$;
3530

    
3531

    
3532
--
3533
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3534
--
3535

    
3536
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3537
idempotent
3538
';
3539

    
3540

    
3541
--
3542
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3543
--
3544

    
3545
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3546
    LANGUAGE sql
3547
    AS $_$
3548
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3549
$_$;
3550

    
3551

    
3552
--
3553
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3554
--
3555

    
3556
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3557
    LANGUAGE sql
3558
    AS $_$
3559
SELECT util.eval(util.mk_set_search_path($1, $2))
3560
$_$;
3561

    
3562

    
3563
--
3564
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3565
--
3566

    
3567
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3568
    LANGUAGE sql STABLE
3569
    AS $_$
3570
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3571
$$||util.show_grants_for($1)
3572
$_$;
3573

    
3574

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

    
3579
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3580
    LANGUAGE sql STABLE
3581
    AS $_$
3582
SELECT string_agg(cmd, '')
3583
FROM
3584
(
3585
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3586
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3587
$$ ELSE '' END) AS cmd
3588
	FROM util.grants_users() f (user_)
3589
) s
3590
$_$;
3591

    
3592

    
3593
--
3594
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3595
--
3596

    
3597
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['c'::text, 'r'::text, 'v'::text]) RETURNS SETOF regclass
3598
    LANGUAGE sql STABLE
3599
    AS $_$
3600
SELECT oid FROM pg_class
3601
WHERE relkind = ANY($3) AND relname ~ $1
3602
AND util.schema_matches(util.schema(relnamespace), $2)
3603
ORDER BY relname
3604
$_$;
3605

    
3606

    
3607
--
3608
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3609
--
3610

    
3611
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3612
    LANGUAGE sql STABLE
3613
    AS $_$
3614
SELECT oid
3615
FROM pg_type
3616
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3617
ORDER BY typname
3618
$_$;
3619

    
3620

    
3621
--
3622
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3623
--
3624

    
3625
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3626
    LANGUAGE sql STABLE
3627
    AS $_$
3628
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3629
$_$;
3630

    
3631

    
3632
--
3633
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3634
--
3635

    
3636
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3637
    LANGUAGE sql IMMUTABLE
3638
    AS $_$
3639
SELECT '^'||util.regexp_quote($1)||'$'
3640
$_$;
3641

    
3642

    
3643
--
3644
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3645
--
3646

    
3647
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3648
    LANGUAGE plpgsql STABLE STRICT
3649
    AS $_$
3650
DECLARE
3651
    hstore hstore;
3652
BEGIN
3653
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3654
        table_||$$))$$ INTO STRICT hstore;
3655
    RETURN hstore;
3656
END;
3657
$_$;
3658

    
3659

    
3660
--
3661
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3662
--
3663

    
3664
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3665
    LANGUAGE sql STABLE
3666
    AS $_$
3667
SELECT COUNT(*) > 0 FROM pg_constraint
3668
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3669
$_$;
3670

    
3671

    
3672
--
3673
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3674
--
3675

    
3676
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3677
gets whether a status flag is set by the presence of a table constraint
3678
';
3679

    
3680

    
3681
--
3682
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3683
--
3684

    
3685
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3686
    LANGUAGE sql
3687
    AS $_$
3688
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3689
||quote_ident($2)||$$ CHECK (true)$$)
3690
$_$;
3691

    
3692

    
3693
--
3694
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3695
--
3696

    
3697
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3698
stores a status flag by the presence of a table constraint.
3699
idempotent.
3700
';
3701

    
3702

    
3703
--
3704
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3705
--
3706

    
3707
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3708
    LANGUAGE sql STABLE
3709
    AS $_$
3710
SELECT util.table_flag__get($1, 'nulls_mapped')
3711
$_$;
3712

    
3713

    
3714
--
3715
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3716
--
3717

    
3718
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
3719
gets whether a table''s NULL-equivalent strings have been replaced with NULL
3720
';
3721

    
3722

    
3723
--
3724
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3725
--
3726

    
3727
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3728
    LANGUAGE sql
3729
    AS $_$
3730
SELECT util.table_flag__set($1, 'nulls_mapped')
3731
$_$;
3732

    
3733

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

    
3738
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3739
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3740
idempotent.
3741
';
3742

    
3743

    
3744
--
3745
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3746
--
3747

    
3748
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3749
    LANGUAGE sql
3750
    AS $_$
3751
-- save data before truncating main table
3752
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3753

    
3754
-- repopulate main table w/ copies column
3755
SELECT util.truncate($1);
3756
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3757
SELECT util.populate_table($1, $$
3758
SELECT (table_).*, copies
3759
FROM (
3760
	SELECT table_, COUNT(*) AS copies
3761
	FROM pg_temp.__copy table_
3762
	GROUP BY table_
3763
) s
3764
$$);
3765

    
3766
-- delete temp table so it doesn't stay around until end of connection
3767
SELECT util.drop_table('pg_temp.__copy');
3768
$_$;
3769

    
3770

    
3771
--
3772
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3773
--
3774

    
3775
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3776
    LANGUAGE plpgsql STRICT
3777
    AS $_$
3778
DECLARE
3779
    row record;
3780
BEGIN
3781
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3782
    LOOP
3783
        IF row.global_name != row.name THEN
3784
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3785
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3786
        END IF;
3787
    END LOOP;
3788
END;
3789
$_$;
3790

    
3791

    
3792
--
3793
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3794
--
3795

    
3796
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3797
idempotent
3798
';
3799

    
3800

    
3801
--
3802
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3803
--
3804

    
3805
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
3806
    LANGUAGE sql
3807
    AS $_$
3808
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
3809
SELECT NULL::void; -- don't fold away functions called in previous query
3810
$_$;
3811

    
3812

    
3813
--
3814
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
3815
--
3816

    
3817
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass, force boolean) IS '
3818
trims table_ to include only columns in the original data
3819

    
3820
by default, cascadingly drops dependent columns so that they don''t prevent
3821
trim() from succeeding. note that this requires the dependent columns to then be
3822
manually re-created.
3823

    
3824
idempotent
3825
';
3826

    
3827

    
3828
--
3829
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3830
--
3831

    
3832
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3833
    LANGUAGE plpgsql STRICT
3834
    AS $_$
3835
BEGIN
3836
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3837
END;
3838
$_$;
3839

    
3840

    
3841
--
3842
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3843
--
3844

    
3845
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3846
idempotent
3847
';
3848

    
3849

    
3850
--
3851
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3852
--
3853

    
3854
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3855
    LANGUAGE sql IMMUTABLE
3856
    AS $_$
3857
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3858
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3859
$_$;
3860

    
3861

    
3862
--
3863
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3864
--
3865

    
3866
CREATE FUNCTION try_create(sql text) RETURNS void
3867
    LANGUAGE plpgsql STRICT
3868
    AS $$
3869
BEGIN
3870
	PERFORM util.eval(sql);
3871
EXCEPTION
3872
WHEN   not_null_violation
3873
		/* trying to add NOT NULL column to parent table, which cascades to
3874
		child table whose values for the new column will be NULL */
3875
	OR wrong_object_type -- trying to alter a view's columns
3876
	OR undefined_column
3877
	OR duplicate_column
3878
THEN NULL;
3879
WHEN datatype_mismatch THEN
3880
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
3881
	ELSE RAISE; -- rethrow
3882
	END IF;
3883
END;
3884
$$;
3885

    
3886

    
3887
--
3888
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3889
--
3890

    
3891
COMMENT ON FUNCTION try_create(sql text) IS '
3892
idempotent
3893
';
3894

    
3895

    
3896
--
3897
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3898
--
3899

    
3900
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3901
    LANGUAGE sql
3902
    AS $_$
3903
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3904
$_$;
3905

    
3906

    
3907
--
3908
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3909
--
3910

    
3911
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3912
idempotent
3913
';
3914

    
3915

    
3916
--
3917
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3918
--
3919

    
3920
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3921
    LANGUAGE sql IMMUTABLE
3922
    AS $_$
3923
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3924
$_$;
3925

    
3926

    
3927
--
3928
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3929
--
3930

    
3931
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3932
a type''s NOT NULL qualifier
3933
';
3934

    
3935

    
3936
--
3937
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3938
--
3939

    
3940
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3941
    LANGUAGE sql STABLE
3942
    AS $_$
3943
SELECT (attname::text, atttypid)::util.col_cast
3944
FROM pg_attribute
3945
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3946
ORDER BY attnum
3947
$_$;
3948

    
3949

    
3950
--
3951
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3952
--
3953

    
3954
CREATE FUNCTION typeof(value anyelement) RETURNS text
3955
    LANGUAGE sql IMMUTABLE
3956
    AS $_$
3957
SELECT util.qual_name(pg_typeof($1))
3958
$_$;
3959

    
3960

    
3961
--
3962
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3963
--
3964

    
3965
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3966
    LANGUAGE plpgsql STABLE
3967
    AS $_$
3968
DECLARE
3969
    type regtype;
3970
BEGIN
3971
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3972
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3973
    RETURN type;
3974
END;
3975
$_$;
3976

    
3977

    
3978
--
3979
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3980
--
3981

    
3982
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3983
    LANGUAGE sql
3984
    AS $_$
3985
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3986
$_$;
3987

    
3988

    
3989
--
3990
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3991
--
3992

    
3993
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3994
auto-appends util to the search_path to enable use of util operators
3995
';
3996

    
3997

    
3998
--
3999
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4000
--
4001

    
4002
CREATE AGGREGATE all_same(anyelement) (
4003
    SFUNC = all_same_transform,
4004
    STYPE = anyarray,
4005
    FINALFUNC = all_same_final
4006
);
4007

    
4008

    
4009
--
4010
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4011
--
4012

    
4013
COMMENT ON AGGREGATE all_same(anyelement) IS '
4014
includes NULLs in comparison
4015
';
4016

    
4017

    
4018
--
4019
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4020
--
4021

    
4022
CREATE AGGREGATE join_strs(text, text) (
4023
    SFUNC = join_strs_transform,
4024
    STYPE = text
4025
);
4026

    
4027

    
4028
--
4029
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4030
--
4031

    
4032
CREATE OPERATOR %== (
4033
    PROCEDURE = "%==",
4034
    LEFTARG = anyelement,
4035
    RIGHTARG = anyelement
4036
);
4037

    
4038

    
4039
--
4040
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4041
--
4042

    
4043
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4044
returns whether the map-keys of the compared values are the same
4045
(mnemonic: % is the Perl symbol for a hash map)
4046

    
4047
should be overridden for types that store both keys and values
4048

    
4049
used in a FULL JOIN to select which columns to join on
4050
';
4051

    
4052

    
4053
--
4054
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4055
--
4056

    
4057
CREATE OPERATOR -> (
4058
    PROCEDURE = map_get,
4059
    LEFTARG = regclass,
4060
    RIGHTARG = text
4061
);
4062

    
4063

    
4064
--
4065
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4066
--
4067

    
4068
CREATE OPERATOR => (
4069
    PROCEDURE = hstore,
4070
    LEFTARG = text[],
4071
    RIGHTARG = text
4072
);
4073

    
4074

    
4075
--
4076
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4077
--
4078

    
4079
COMMENT ON OPERATOR => (text[], text) IS '
4080
usage: array[''key1'', ...]::text[] => ''value''
4081
';
4082

    
4083

    
4084
--
4085
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4086
--
4087

    
4088
CREATE OPERATOR ?*>= (
4089
    PROCEDURE = is_populated_more_often_than,
4090
    LEFTARG = anyelement,
4091
    RIGHTARG = anyelement
4092
);
4093

    
4094

    
4095
--
4096
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4097
--
4098

    
4099
CREATE OPERATOR ?>= (
4100
    PROCEDURE = is_more_complete_than,
4101
    LEFTARG = anyelement,
4102
    RIGHTARG = anyelement
4103
);
4104

    
4105

    
4106
--
4107
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4108
--
4109

    
4110
CREATE OPERATOR ||% (
4111
    PROCEDURE = concat_esc,
4112
    LEFTARG = text,
4113
    RIGHTARG = text
4114
);
4115

    
4116

    
4117
--
4118
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4119
--
4120

    
4121
COMMENT ON OPERATOR ||% (text, text) IS '
4122
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4123
';
4124

    
4125

    
4126
--
4127
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4128
--
4129

    
4130
CREATE TABLE map (
4131
    "from" text NOT NULL,
4132
    "to" text,
4133
    filter text,
4134
    notes text
4135
);
4136

    
4137

    
4138
--
4139
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4140
--
4141

    
4142

    
4143

    
4144
--
4145
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4146
--
4147

    
4148

    
4149

    
4150
--
4151
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4152
--
4153

    
4154
ALTER TABLE ONLY map
4155
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4156

    
4157

    
4158
--
4159
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4160
--
4161

    
4162
ALTER TABLE ONLY map
4163
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4164

    
4165

    
4166
--
4167
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4168
--
4169

    
4170
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4171

    
4172

    
4173
--
4174
-- PostgreSQL database dump complete
4175
--
4176

    
(20-20/30)