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: db_item; Type: TYPE; Schema: util; Owner: -
76
--
77

    
78
CREATE TYPE db_item AS (
79
	path text,
80
	def text
81
);
82

    
83

    
84
--
85
-- Name: range; Type: TYPE; Schema: util; Owner: -
86
--
87

    
88
CREATE TYPE range AS (
89
	lower numeric,
90
	upper numeric,
91
	bounds text
92
);
93

    
94

    
95
--
96
-- Name: TYPE range; Type: COMMENT; Schema: util; Owner: -
97
--
98

    
99
COMMENT ON TYPE range IS '
100
allows wraparound ranges (which use a modulus system such as geocoordinates)
101
';
102

    
103

    
104
--
105
-- Name: restore_views_info; Type: TYPE; Schema: util; Owner: -
106
--
107

    
108
CREATE TYPE restore_views_info AS (
109
	views db_item[]
110
);
111

    
112

    
113
--
114
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
115
--
116

    
117
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
118
    LANGUAGE sql IMMUTABLE
119
    AS $_$
120
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
121
$_$;
122

    
123

    
124
--
125
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
126
--
127

    
128
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
129
    LANGUAGE sql IMMUTABLE
130
    AS $_$
131
SELECT bool_and(value)
132
FROM
133
(VALUES
134
      ($1)
135
    , ($2)
136
    , ($3)
137
    , ($4)
138
    , ($5)
139
)
140
AS v (value)
141
$_$;
142

    
143

    
144
--
145
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
146
--
147

    
148
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
149
_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.
150
';
151

    
152

    
153
--
154
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
155
--
156

    
157
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
158
    LANGUAGE sql IMMUTABLE
159
    AS $_$
160
SELECT avg(value)
161
FROM
162
(VALUES
163
      ($1)
164
    , ($2)
165
    , ($3)
166
    , ($4)
167
    , ($5)
168
)
169
AS v (value)
170
$_$;
171

    
172

    
173
--
174
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
175
--
176

    
177
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
178
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
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)
181
FROM 
182
(
183
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
184
    UNION ALL
185
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
186
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
187
)
188
matches (g)
189
$_$;
190

    
191

    
192
--
193
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
194
--
195

    
196
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
197
    LANGUAGE sql IMMUTABLE
198
    AS $_$
199
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
200
FROM
201
(VALUES
202
      ($1)
203
    , ($2/60)
204
    , ($3/60/60)
205
)
206
AS v (value)
207
$_$;
208

    
209

    
210
--
211
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
212
--
213

    
214
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
215
    LANGUAGE sql IMMUTABLE
216
    AS $_$
217
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
218
$_$;
219

    
220

    
221
--
222
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
223
--
224

    
225
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
226
    LANGUAGE sql IMMUTABLE
227
    AS $_$
228
SELECT $1 = $2
229
$_$;
230

    
231

    
232
--
233
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
234
--
235

    
236
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
237
    LANGUAGE sql IMMUTABLE
238
    AS $_$
239
-- Fix dates after threshold date
240
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
241
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
242
$_$;
243

    
244

    
245
--
246
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
247
--
248

    
249
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
250
    LANGUAGE sql IMMUTABLE
251
    AS $_$
252
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
253
$_$;
254

    
255

    
256
--
257
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
258
--
259

    
260
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
261
    LANGUAGE sql IMMUTABLE
262
    AS $_$
263
SELECT util._if($1 != '', $2, $3)
264
$_$;
265

    
266

    
267
--
268
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
269
--
270

    
271
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
272
    LANGUAGE sql IMMUTABLE
273
    AS $_$
274
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
275
$_$;
276

    
277

    
278
--
279
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
280
--
281

    
282
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
283
    LANGUAGE sql IMMUTABLE
284
    AS $_$
285
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
286
$_$;
287

    
288

    
289
--
290
-- Name: _km_to_m(double precision); Type: FUNCTION; Schema: util; Owner: -
291
--
292

    
293
CREATE FUNCTION _km_to_m(value double precision) RETURNS double precision
294
    LANGUAGE sql IMMUTABLE
295
    AS $_$
296
SELECT $1*1000.
297
$_$;
298

    
299

    
300
--
301
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
302
--
303

    
304
CREATE FUNCTION _label(label text, value text) RETURNS text
305
    LANGUAGE sql IMMUTABLE
306
    AS $_$
307
SELECT coalesce($1 || ': ', '') || $2
308
$_$;
309

    
310

    
311
--
312
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
313
--
314

    
315
CREATE FUNCTION _lowercase(value text) RETURNS text
316
    LANGUAGE sql IMMUTABLE
317
    AS $_$
318
SELECT lower($1)
319
$_$;
320

    
321

    
322
--
323
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
324
--
325

    
326
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
327
    LANGUAGE plpgsql IMMUTABLE STRICT
328
    AS $$
329
DECLARE
330
    result value%TYPE := util._map(map, value::text)::unknown;
331
BEGIN
332
    RETURN result;
333
END;
334
$$;
335

    
336

    
337
--
338
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
339
--
340

    
341
CREATE FUNCTION _map(map hstore, value text) RETURNS text
342
    LANGUAGE plpgsql IMMUTABLE STRICT
343
    AS $$
344
DECLARE
345
    match text := map -> value;
346
BEGIN
347
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
348
        match := map -> '*'; -- use default entry
349
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
350
        END IF;
351
    END IF;
352
    
353
    -- Interpret result
354
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
355
    ELSIF match = '*' THEN RETURN value;
356
    ELSE RETURN match;
357
    END IF;
358
END;
359
$$;
360

    
361

    
362
--
363
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
364
--
365

    
366
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
367
    LANGUAGE sql IMMUTABLE
368
    AS $_$
369
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
370
$_$;
371

    
372

    
373
--
374
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
375
--
376

    
377
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
378
    LANGUAGE sql IMMUTABLE
379
    AS $_$
380
SELECT util.join_strs(value, '; ')
381
FROM
382
(
383
    SELECT *
384
    FROM
385
    (
386
        SELECT
387
        DISTINCT ON (value)
388
        *
389
        FROM
390
        (VALUES
391
              (1, $1)
392
            , (2, $2)
393
            , (3, $3)
394
            , (4, $4)
395
            , (5, $5)
396
            , (6, $6)
397
            , (7, $7)
398
            , (8, $8)
399
            , (9, $9)
400
            , (10, $10)
401
        )
402
        AS v (sort_order, value)
403
        WHERE value IS NOT NULL
404
    )
405
    AS v
406
    ORDER BY sort_order
407
)
408
AS v
409
$_$;
410

    
411

    
412
--
413
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
414
--
415

    
416
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
417
    LANGUAGE sql IMMUTABLE
418
    AS $_$
419
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
420
$_$;
421

    
422

    
423
--
424
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
425
--
426

    
427
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
428
    LANGUAGE sql IMMUTABLE
429
    AS $_$
430
SELECT util.join_strs(value, ' ')
431
FROM
432
(
433
    SELECT *
434
    FROM
435
    (
436
        SELECT
437
        DISTINCT ON (value)
438
        *
439
        FROM
440
        (VALUES
441
              (1, $1)
442
            , (2, $2)
443
            , (3, $3)
444
            , (4, $4)
445
            , (5, $5)
446
            , (6, $6)
447
            , (7, $7)
448
            , (8, $8)
449
            , (9, $9)
450
            , (10, $10)
451
        )
452
        AS v (sort_order, value)
453
        WHERE value IS NOT NULL
454
    )
455
    AS v
456
    ORDER BY sort_order
457
)
458
AS v
459
$_$;
460

    
461

    
462
--
463
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
464
--
465

    
466
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
467
    LANGUAGE sql IMMUTABLE
468
    AS $_$
469
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
470
$_$;
471

    
472

    
473
--
474
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
475
--
476

    
477
CREATE FUNCTION _not(value boolean) RETURNS boolean
478
    LANGUAGE sql IMMUTABLE
479
    AS $_$
480
SELECT NOT $1
481
$_$;
482

    
483

    
484
--
485
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
486
--
487

    
488
CREATE FUNCTION _now() RETURNS timestamp with time zone
489
    LANGUAGE sql STABLE
490
    AS $$
491
SELECT now()
492
$$;
493

    
494

    
495
--
496
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
497
--
498

    
499
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
500
    LANGUAGE sql IMMUTABLE
501
    AS $_$
502
SELECT util."_nullIf"($1, $2, $3::util.datatype)
503
$_$;
504

    
505

    
506
--
507
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
508
--
509

    
510
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
511
    LANGUAGE plpgsql IMMUTABLE
512
    AS $$
513
DECLARE
514
    type util.datatype NOT NULL := type; -- add NOT NULL
515
BEGIN
516
    IF type = 'str' THEN RETURN nullif(value::text, "null");
517
    -- Invalid value is ignored, but invalid null value generates error
518
    ELSIF type = 'float' THEN
519
        DECLARE
520
            -- Outside the try block so that invalid null value generates error
521
            "null" double precision := "null"::double precision;
522
        BEGIN
523
            RETURN nullif(value::double precision, "null");
524
        EXCEPTION
525
            WHEN data_exception THEN RETURN value; -- ignore invalid value
526
        END;
527
    END IF;
528
END;
529
$$;
530

    
531

    
532
--
533
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
534
--
535

    
536
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
537
    LANGUAGE sql IMMUTABLE
538
    AS $_$
539
SELECT bool_or(value)
540
FROM
541
(VALUES
542
      ($1)
543
    , ($2)
544
    , ($3)
545
    , ($4)
546
    , ($5)
547
)
548
AS v (value)
549
$_$;
550

    
551

    
552
--
553
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
554
--
555

    
556
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
557
_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.
558
';
559

    
560

    
561
--
562
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
563
--
564

    
565
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
566
    LANGUAGE sql IMMUTABLE
567
    AS $_$
568
SELECT $2 - $1
569
$_$;
570

    
571

    
572
--
573
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
574
--
575

    
576
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
577
    LANGUAGE sql IMMUTABLE
578
    AS $_$
579
SELECT regexp_split_to_table($1, $2)
580
$_$;
581

    
582

    
583
--
584
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
585
--
586

    
587
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
588
    LANGUAGE sql STABLE
589
    AS $_$
590
SELECT util.derived_cols($1, $2)
591
UNION
592
SELECT util.eval2set($$
593
SELECT col
594
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
595
JOIN $$||$2||$$ ON "to" = col
596
WHERE "from" LIKE ':%'
597
$$, NULL::text)
598
$_$;
599

    
600

    
601
--
602
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
603
--
604

    
605
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
606
gets table_''s added columns (all the columns not in the original data)
607
';
608

    
609

    
610
--
611
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
612
--
613

    
614
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
615
    LANGUAGE sql IMMUTABLE
616
    AS $_$
617
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
618
$_$;
619

    
620

    
621
--
622
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
623
--
624

    
625
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
626
    LANGUAGE plpgsql IMMUTABLE
627
    AS $$
628
DECLARE
629
	value_cmp         state%TYPE = ARRAY[value];
630
	state             state%TYPE = COALESCE(state, value_cmp);
631
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
632
BEGIN
633
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
634
END;
635
$$;
636

    
637

    
638
--
639
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
640
--
641

    
642
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
643
    LANGUAGE sql
644
    AS $_$
645
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
646
$_$;
647

    
648

    
649
--
650
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
651
--
652

    
653
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
654
    LANGUAGE sql
655
    AS $_$
656
SELECT util.set_comment($1, concat(util.comment($1), $2))
657
$_$;
658

    
659

    
660
--
661
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
662
--
663

    
664
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
665
comment: must start and end with a newline
666
';
667

    
668

    
669
--
670
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
671
--
672

    
673
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
674
    LANGUAGE sql IMMUTABLE
675
    AS $_$
676
SELECT pg_catalog.array_fill($1, ARRAY[$2])
677
$_$;
678

    
679

    
680
--
681
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
682
--
683

    
684
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
685
    LANGUAGE sql IMMUTABLE
686
    AS $_$
687
SELECT util.array_length($1, 1)
688
$_$;
689

    
690

    
691
--
692
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
693
--
694

    
695
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
696
    LANGUAGE sql IMMUTABLE
697
    AS $_$
698
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
699
$_$;
700

    
701

    
702
--
703
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
704
--
705

    
706
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
707
returns 0 instead of NULL for empty arrays
708
';
709

    
710

    
711
--
712
-- Name: array_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
713
--
714

    
715
CREATE FUNCTION array_reverse("array" anyarray) RETURNS anyarray
716
    LANGUAGE sql IMMUTABLE
717
    AS $_$
718
SELECT array(SELECT elem FROM util.in_reverse($1) elem)
719
$_$;
720

    
721

    
722
--
723
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
724
--
725

    
726
CREATE FUNCTION auto_rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
727
    LANGUAGE sql
728
    AS $_$
729
SELECT CASE WHEN util.freq_always_1($1, $2)
730
THEN util.rm_freq($1, $2)
731
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
732
END
733
$_$;
734

    
735

    
736
--
737
-- Name: bounding_box(range, range); Type: FUNCTION; Schema: util; Owner: -
738
--
739

    
740
CREATE FUNCTION bounding_box(latitude_range_deg range, longitude_range_deg range) RETURNS postgis.geography
741
    LANGUAGE sql IMMUTABLE
742
    AS $_$
743
/* don't use st_makebox2d() because it doesn't support geocoordinate wraparound
744
(it is not SRID-aware) */
745
SELECT postgis.st_makeenvelope(
746
  /*xmin=*/$2.lower, /*ymin=*/$1.lower
747
, /*xmax=*/$2.upper, /*ymax=*/$1.upper
748
, /*WGS84*/4326
749
)::postgis.geography
750
$_$;
751

    
752

    
753
--
754
-- Name: FUNCTION bounding_box(latitude_range_deg range, longitude_range_deg range); Type: COMMENT; Schema: util; Owner: -
755
--
756

    
757
COMMENT ON FUNCTION bounding_box(latitude_range_deg range, longitude_range_deg range) IS '
758
usage:
759
SET search_path = util; -- for ~ operator
760
SELECT util.bounding_box(lower_lat ~ upper_lat, lower_long ~ upper_long);
761

    
762
**WARNING**: the geography type stores all edges as arcs of great circles,
763
resulting in the latitude lines bulging outward from the true bounding box.
764
this will create false positives above and below the bounding box.
765
';
766

    
767

    
768
--
769
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
770
--
771

    
772
CREATE FUNCTION "cast"(value text, ret_type_null anyelement) RETURNS anyelement
773
    LANGUAGE plpgsql IMMUTABLE
774
    AS $$
775
/* must use LANGUAGE plpgsql because LANGUAGE sql does not assignment-cast the
776
return value, causing a type mismatch */
777
BEGIN
778
	-- will then be assignment-cast to return type via INOUT
779
	RETURN value::cstring;
780
END;
781
$$;
782

    
783

    
784
--
785
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
786
--
787

    
788
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
789
allows casting to an arbitrary type without eval()
790

    
791
usage:
792
SELECT util.cast(''value'', NULL::integer);
793

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

    
798
ret_type_null: NULL::ret_type
799
';
800

    
801

    
802
--
803
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
804
--
805

    
806
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
807
    LANGUAGE sql STABLE
808
    AS $_$
809
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
810
$_$;
811

    
812

    
813
--
814
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
815
--
816

    
817
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
818
    LANGUAGE plpgsql STRICT
819
    AS $_$
820
BEGIN
821
    -- not yet clustered (ARRAY[] compares NULLs literally)
822
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
823
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
824
    END IF;
825
END;
826
$_$;
827

    
828

    
829
--
830
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
831
--
832

    
833
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
834
idempotent
835
';
836

    
837

    
838
--
839
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
840
--
841

    
842
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
843
    LANGUAGE sql IMMUTABLE
844
    AS $_$
845
SELECT value
846
FROM unnest($1) value
847
WHERE value IS NOT NULL
848
LIMIT 1
849
$_$;
850

    
851

    
852
--
853
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
854
--
855

    
856
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
857
uses:
858
* coalescing array elements or rows together
859
* forcing evaluation of all values of a COALESCE()
860
';
861

    
862

    
863
--
864
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
865
--
866

    
867
CREATE FUNCTION col__min(col col_ref) RETURNS integer
868
    LANGUAGE sql STABLE
869
    AS $_$
870
SELECT util.eval2val($$
871
SELECT $$||quote_ident($1.name)||$$
872
FROM $$||$1.table_||$$
873
ORDER BY $$||quote_ident($1.name)||$$ ASC
874
LIMIT 1
875
$$, NULL::integer)
876
$_$;
877

    
878

    
879
--
880
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
881
--
882

    
883
CREATE FUNCTION col_comment(col col_ref) RETURNS text
884
    LANGUAGE plpgsql STABLE STRICT
885
    AS $$
886
DECLARE
887
	comment text;
888
BEGIN
889
	SELECT description
890
	FROM pg_attribute
891
	LEFT JOIN pg_description ON objoid = attrelid
892
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
893
	WHERE attrelid = col.table_ AND attname = col.name
894
	INTO STRICT comment
895
	;
896
	RETURN comment;
897
EXCEPTION
898
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
899
END;
900
$$;
901

    
902

    
903
--
904
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
905
--
906

    
907
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
908
    LANGUAGE plpgsql STABLE STRICT
909
    AS $$
910
DECLARE
911
	default_sql text;
912
BEGIN
913
	SELECT adsrc
914
	FROM pg_attribute
915
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
916
	WHERE attrelid = col.table_ AND attname = col.name
917
	INTO STRICT default_sql
918
	;
919
	RETURN default_sql;
920
EXCEPTION
921
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
922
END;
923
$$;
924

    
925

    
926
--
927
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
928
--
929

    
930
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
931
    LANGUAGE sql STABLE
932
    AS $_$
933
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
934
$_$;
935

    
936

    
937
--
938
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
939
--
940

    
941
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
942
ret_type_null: NULL::ret_type
943
';
944

    
945

    
946
--
947
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
948
--
949

    
950
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
951
    LANGUAGE plpgsql STRICT
952
    AS $$
953
BEGIN
954
    PERFORM util.col_type(col);
955
    RETURN true;
956
EXCEPTION
957
    WHEN undefined_column THEN RETURN false;
958
END;
959
$$;
960

    
961

    
962
--
963
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
964
--
965

    
966
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
967
    LANGUAGE plpgsql STABLE STRICT
968
    AS $$
969
DECLARE
970
    prefix text := util.name(type)||'.';
971
BEGIN
972
    RETURN QUERY
973
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
974
        FROM util.col_names(type) f (name_);
975
END;
976
$$;
977

    
978

    
979
--
980
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
981
--
982

    
983
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
984
    LANGUAGE sql STABLE
985
    AS $_$
986
SELECT attname::text
987
FROM pg_attribute
988
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
989
ORDER BY attnum
990
$_$;
991

    
992

    
993
--
994
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
995
--
996

    
997
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
998
    LANGUAGE plpgsql STABLE STRICT
999
    AS $_$
1000
BEGIN
1001
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
1002
END;
1003
$_$;
1004

    
1005

    
1006
--
1007
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
1008
--
1009

    
1010
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
1011
    LANGUAGE plpgsql STABLE STRICT
1012
    AS $$
1013
DECLARE
1014
    type regtype;
1015
BEGIN
1016
    SELECT atttypid FROM pg_attribute
1017
    WHERE attrelid = col.table_ AND attname = col.name
1018
    INTO STRICT type
1019
    ;
1020
    RETURN type;
1021
EXCEPTION
1022
    WHEN no_data_found THEN
1023
        RAISE undefined_column USING MESSAGE =
1024
            concat('undefined column: ', col.name);
1025
END;
1026
$$;
1027

    
1028

    
1029
--
1030
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
1031
--
1032

    
1033
CREATE FUNCTION comment(element oid) RETURNS text
1034
    LANGUAGE sql STABLE
1035
    AS $_$
1036
SELECT description FROM pg_description WHERE objoid = $1
1037
$_$;
1038

    
1039

    
1040
--
1041
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
1042
--
1043

    
1044
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
1045
    LANGUAGE sql IMMUTABLE
1046
    AS $_$
1047
SELECT util.esc_name__append($2, $1)
1048
$_$;
1049

    
1050

    
1051
--
1052
-- Name: contained_within(postgis.geography, postgis.geography); Type: FUNCTION; Schema: util; Owner: -
1053
--
1054

    
1055
CREATE FUNCTION contained_within("inner" postgis.geography, "outer" postgis.geography) RETURNS boolean
1056
    LANGUAGE sql IMMUTABLE
1057
    SET search_path TO postgis
1058
    AS $_$
1059
/* search_path: st_coveredby() needs postgis to be in the search_path */
1060
SELECT postgis.st_coveredby($1, $2)
1061
$_$;
1062

    
1063

    
1064
--
1065
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
1066
--
1067

    
1068
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
1069
    LANGUAGE sql IMMUTABLE
1070
    AS $_$
1071
SELECT position($1 in $2) > 0 /*1-based offset*/
1072
$_$;
1073

    
1074

    
1075
--
1076
-- Name: copy(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1077
--
1078

    
1079
CREATE FUNCTION copy(from_ regclass, to_ text) RETURNS void
1080
    LANGUAGE sql
1081
    AS $_$
1082
SELECT util.copy_struct($1, $2);
1083
SELECT util.copy_data($1, $2);
1084
$_$;
1085

    
1086

    
1087
--
1088
-- Name: copy_data(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1089
--
1090

    
1091
CREATE FUNCTION copy_data(from_ regclass, to_ regclass) RETURNS void
1092
    LANGUAGE sql
1093
    AS $_$
1094
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT * FROM $$||$1)
1095
$_$;
1096

    
1097

    
1098
--
1099
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1100
--
1101

    
1102
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1103
    LANGUAGE sql
1104
    AS $_$
1105
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1106
$_$;
1107

    
1108

    
1109
--
1110
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1111
--
1112

    
1113
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1114
    LANGUAGE sql
1115
    AS $_$
1116
SELECT util.materialize_view($2, $1)
1117
$_$;
1118

    
1119

    
1120
--
1121
-- Name: create_if_not_exists(text, text); Type: FUNCTION; Schema: util; Owner: -
1122
--
1123

    
1124
CREATE FUNCTION create_if_not_exists(sql text, relation text DEFAULT NULL::text) RETURNS void
1125
    LANGUAGE plpgsql
1126
    AS $$
1127
BEGIN
1128
	/* always generate standard exception if exists, even if table definition
1129
	would be invalid (which generates a variety of exceptions) */
1130
	IF util.relation_exists(relation) THEN
1131
		PERFORM util.raise('NOTICE', relation||' already exists, skipping');
1132
		RAISE duplicate_table;
1133
	END IF;
1134
	PERFORM util.eval(sql);
1135
EXCEPTION
1136
WHEN   duplicate_table
1137
	OR duplicate_object -- eg. constraint
1138
	OR duplicate_column
1139
	OR duplicate_function
1140
THEN NULL;
1141
WHEN invalid_table_definition THEN
1142
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1143
	ELSE RAISE;
1144
	END IF;
1145
END;
1146
$$;
1147

    
1148

    
1149
--
1150
-- Name: FUNCTION create_if_not_exists(sql text, relation text); Type: COMMENT; Schema: util; Owner: -
1151
--
1152

    
1153
COMMENT ON FUNCTION create_if_not_exists(sql text, relation text) IS '
1154
idempotent
1155
';
1156

    
1157

    
1158
--
1159
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1160
--
1161

    
1162
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1163
    LANGUAGE sql STABLE
1164
    AS $$
1165
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1166
$$;
1167

    
1168

    
1169
--
1170
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1171
--
1172

    
1173
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1174
    LANGUAGE sql IMMUTABLE
1175
    AS $_$
1176
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1177
$_$;
1178

    
1179

    
1180
--
1181
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1182
--
1183

    
1184
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1185
    LANGUAGE sql IMMUTABLE
1186
    AS $_$
1187
SELECT util.debug_print_value('returns: ', $1, $2);
1188
SELECT $1;
1189
$_$;
1190

    
1191

    
1192
--
1193
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1194
--
1195

    
1196
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1197
    LANGUAGE sql IMMUTABLE
1198
    AS $_$
1199
/* newline before so the query starts at the beginning of the line.
1200
newline after to visually separate queries from one another. */
1201
SELECT util.raise('NOTICE', $$
1202
$$||util.runnable_sql($1)||$$
1203
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1204
$_$;
1205

    
1206

    
1207
--
1208
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1209
--
1210

    
1211
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1212
    LANGUAGE sql IMMUTABLE
1213
    AS $_$
1214
SELECT util.raise('NOTICE', concat($1,
1215
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1216
$$)
1217
$_$;
1218

    
1219

    
1220
--
1221
-- Name: debug_print_var(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1222
--
1223

    
1224
CREATE FUNCTION debug_print_var(var text, value anyelement, encode boolean DEFAULT false) RETURNS void
1225
    LANGUAGE sql IMMUTABLE
1226
    AS $_$
1227
/* can't use EXECUTE in the caller because "No substitution of PL/pgSQL
1228
variables is done on the computed command string"
1229
(http://www.postgresql.org/docs/9.3/static/plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN) */
1230
SELECT util.debug_print_value($1||' = ', $2, $3)
1231
$_$;
1232

    
1233

    
1234
--
1235
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1236
--
1237

    
1238
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1239
    LANGUAGE sql STABLE
1240
    AS $_$
1241
SELECT util.eval2set($$
1242
SELECT col
1243
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1244
LEFT JOIN $$||$2||$$ ON "to" = col
1245
WHERE "from" IS NULL
1246
$$, NULL::text)
1247
$_$;
1248

    
1249

    
1250
--
1251
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1252
--
1253

    
1254
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1255
gets table_''s derived columns (all the columns not in the names table)
1256
';
1257

    
1258

    
1259
--
1260
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1261
--
1262

    
1263
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1264
    LANGUAGE sql
1265
    AS $_$
1266
-- create a diff when the # of copies of a row differs between the tables
1267
SELECT util.to_freq($1);
1268
SELECT util.to_freq($2);
1269
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1270

    
1271
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1272
$_$;
1273

    
1274

    
1275
--
1276
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1277
--
1278

    
1279
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1280
usage:
1281
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1282

    
1283
col_type_null (*required*): NULL::shared_base_type
1284
';
1285

    
1286

    
1287
--
1288
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1289
--
1290

    
1291
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
1292
    LANGUAGE plpgsql
1293
    SET search_path TO pg_temp
1294
    AS $_$
1295
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1296
changes of search_path (schema elements are bound at inline time rather than
1297
runtime) */
1298
/* function option search_path is needed to limit the effects of
1299
`SET LOCAL search_path` to the current function */
1300
BEGIN
1301
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1302
	
1303
	PERFORM util.mk_keys_func(pg_typeof($3));
1304
	RETURN QUERY
1305
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1306
$$/* need to explicitly cast each side to the return type because this does not
1307
happen automatically even when an implicit cast is available */
1308
  left_::$$||util.typeof($3)||$$
1309
, right_::$$||util.typeof($3)
1310
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1311
the *same* base type, *even though* this is optional when using a custom %== */
1312
, util._if($4, $$true/*= CROSS JOIN*/$$,
1313
$$ left_::$$||util.typeof($3)||$$
1314
%== right_::$$||util.typeof($3)||$$
1315
	-- refer to EXPLAIN output for expansion of %==$$
1316
)
1317
,     $$         left_::$$||util.typeof($3)||$$
1318
IS DISTINCT FROM right_::$$||util.typeof($3)
1319
), $3)
1320
	;
1321
END;
1322
$_$;
1323

    
1324

    
1325
--
1326
-- 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: -
1327
--
1328

    
1329
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1330
col_type_null (*required*): NULL::col_type
1331
single_row: whether the tables consist of a single row, which should be
1332
	displayed side-by-side
1333

    
1334
to match up rows using a subset of the columns, create a custom keys() function
1335
which returns this subset as a record:
1336
-- note that OUT parameters for the returned fields are *not* needed
1337
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1338
  RETURNS record AS
1339
$BODY$
1340
SELECT ($1.key_field_0, $1.key_field_1)
1341
$BODY$
1342
  LANGUAGE sql IMMUTABLE
1343
  COST 100;
1344

    
1345

    
1346
to run EXPLAIN on the FULL JOIN query:
1347
# run this function
1348
# look for a NOTICE containing the expanded query that it ran
1349
# run EXPLAIN on this expanded query
1350
';
1351

    
1352

    
1353
--
1354
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1355
--
1356

    
1357
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
1358
    LANGUAGE sql
1359
    AS $_$
1360
SELECT * FROM util.diff($1::text, $2::text, $3,
1361
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1362
$_$;
1363

    
1364

    
1365
--
1366
-- 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: -
1367
--
1368

    
1369
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1370
helper function used by diff(regclass, regclass)
1371

    
1372
usage:
1373
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1374

    
1375
col_type_null (*required*): NULL::shared_base_type
1376
';
1377

    
1378

    
1379
--
1380
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1381
--
1382

    
1383
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1384
    LANGUAGE sql
1385
    AS $_$
1386
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1387
$_$;
1388

    
1389

    
1390
--
1391
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1392
--
1393

    
1394
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1395
idempotent
1396
';
1397

    
1398

    
1399
--
1400
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1401
--
1402

    
1403
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1404
    LANGUAGE sql
1405
    AS $_$
1406
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1407
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1408
$_$;
1409

    
1410

    
1411
--
1412
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1413
--
1414

    
1415
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1416
idempotent
1417
';
1418

    
1419

    
1420
--
1421
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1422
--
1423

    
1424
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1425
    LANGUAGE sql
1426
    AS $_$
1427
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1428
SELECT NULL::void; -- don't fold away functions called in previous query
1429
$_$;
1430

    
1431

    
1432
--
1433
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1434
--
1435

    
1436
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1437
idempotent
1438
';
1439

    
1440

    
1441
--
1442
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1443
--
1444

    
1445
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1446
    LANGUAGE sql
1447
    AS $_$
1448
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1449
included in the debug SQL */
1450
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1451
$_$;
1452

    
1453

    
1454
--
1455
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1456
--
1457

    
1458
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1459
    LANGUAGE sql
1460
    AS $_$
1461
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1462
||util._if($3, $$ CASCADE$$, ''::text))
1463
$_$;
1464

    
1465

    
1466
--
1467
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1468
--
1469

    
1470
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1471
idempotent
1472
';
1473

    
1474

    
1475
--
1476
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1477
--
1478

    
1479
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1480
    LANGUAGE sql
1481
    AS $_$
1482
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1483
$_$;
1484

    
1485

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

    
1490
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1491
    LANGUAGE sql
1492
    AS $_$
1493
SELECT util.debug_print_func_call(util.quote_func_call(
1494
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1495
util.quote_typed($3)))
1496
;
1497
SELECT util.drop_relation(relation, $3)
1498
FROM util.show_relations_like($1, $2) relation
1499
;
1500
SELECT NULL::void; -- don't fold away functions called in previous query
1501
$_$;
1502

    
1503

    
1504
--
1505
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1506
--
1507

    
1508
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1509
    LANGUAGE sql
1510
    AS $_$
1511
SELECT util.drop_relation('TABLE', $1, $2)
1512
$_$;
1513

    
1514

    
1515
--
1516
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1517
--
1518

    
1519
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1520
idempotent
1521
';
1522

    
1523

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

    
1528
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1529
    LANGUAGE sql
1530
    AS $_$
1531
SELECT util.drop_relation('VIEW', $1, $2)
1532
$_$;
1533

    
1534

    
1535
--
1536
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1537
--
1538

    
1539
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1540
idempotent
1541
';
1542

    
1543

    
1544
--
1545
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1546
--
1547

    
1548
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1549
    LANGUAGE sql IMMUTABLE
1550
    AS $_$
1551
SELECT util.array_fill($1, 0)
1552
$_$;
1553

    
1554

    
1555
--
1556
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1557
--
1558

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

    
1563

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

    
1568
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1569
    LANGUAGE sql IMMUTABLE
1570
    AS $_$
1571
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1572
$_$;
1573

    
1574

    
1575
--
1576
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1577
--
1578

    
1579
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1580
    LANGUAGE sql IMMUTABLE
1581
    AS $_$
1582
SELECT regexp_replace($2, '("?)$', $1||'\1')
1583
$_$;
1584

    
1585

    
1586
--
1587
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1588
--
1589

    
1590
CREATE FUNCTION eval(queries text[]) RETURNS void
1591
    LANGUAGE sql
1592
    AS $_$
1593
SELECT util.eval(query) FROM unnest($1) query;
1594
SELECT NULL::void; -- don't fold away functions called in previous query
1595
$_$;
1596

    
1597

    
1598
--
1599
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1600
--
1601

    
1602
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1603
    LANGUAGE plpgsql
1604
    AS $$
1605
BEGIN
1606
	sql = util.view_def_to_orig(sql); -- restore user's intent
1607
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1608
	EXECUTE sql;
1609
END;
1610
$$;
1611

    
1612

    
1613
--
1614
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1615
--
1616

    
1617
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1618
    LANGUAGE plpgsql
1619
    AS $$
1620
BEGIN
1621
	PERFORM util.debug_print_sql(sql);
1622
	RETURN QUERY EXECUTE sql;
1623
END;
1624
$$;
1625

    
1626

    
1627
--
1628
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1629
--
1630

    
1631
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1632
col_type_null (*required*): NULL::col_type
1633
';
1634

    
1635

    
1636
--
1637
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1638
--
1639

    
1640
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1641
    LANGUAGE plpgsql
1642
    AS $$
1643
BEGIN
1644
	PERFORM util.debug_print_sql(sql);
1645
	RETURN QUERY EXECUTE sql;
1646
END;
1647
$$;
1648

    
1649

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

    
1654
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1655
    LANGUAGE plpgsql
1656
    AS $$
1657
BEGIN
1658
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1659
	RETURN QUERY EXECUTE sql;
1660
END;
1661
$$;
1662

    
1663

    
1664
--
1665
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1666
--
1667

    
1668
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1669
    LANGUAGE plpgsql STABLE
1670
    AS $$
1671
DECLARE
1672
	ret_val ret_type_null%TYPE;
1673
BEGIN
1674
	PERFORM util.debug_print_sql(sql);
1675
	EXECUTE sql INTO STRICT ret_val;
1676
	RETURN ret_val;
1677
END;
1678
$$;
1679

    
1680

    
1681
--
1682
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1683
--
1684

    
1685
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1686
ret_type_null: NULL::ret_type
1687
';
1688

    
1689

    
1690
--
1691
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1692
--
1693

    
1694
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1695
    LANGUAGE sql
1696
    AS $_$
1697
SELECT util.eval2val($$SELECT $$||$1, $2)
1698
$_$;
1699

    
1700

    
1701
--
1702
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1703
--
1704

    
1705
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1706
ret_type_null: NULL::ret_type
1707
';
1708

    
1709

    
1710
--
1711
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1712
--
1713

    
1714
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1715
    LANGUAGE sql
1716
    AS $_$
1717
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1718
$_$;
1719

    
1720

    
1721
--
1722
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1723
--
1724

    
1725
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1726
sql: can be NULL, which will be passed through
1727
ret_type_null: NULL::ret_type
1728
';
1729

    
1730

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

    
1735
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1736
    LANGUAGE sql STABLE
1737
    AS $_$
1738
SELECT col_name
1739
FROM unnest($2) s (col_name)
1740
WHERE util.col_exists(($1, col_name))
1741
$_$;
1742

    
1743

    
1744
--
1745
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1746
--
1747

    
1748
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1749
    LANGUAGE sql
1750
    SET client_min_messages TO 'error'
1751
    AS $_$
1752
/* `client_min_messages = ERROR`: EXPLAIN apparently runs IMMUTABLE functions in
1753
the query, so this prevents displaying any log messages printed by them */
1754
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1755
$_$;
1756

    
1757

    
1758
--
1759
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1760
--
1761

    
1762
CREATE FUNCTION explain2notice(sql text) RETURNS void
1763
    LANGUAGE sql
1764
    AS $_$
1765
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1766
$_$;
1767

    
1768

    
1769
--
1770
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1771
--
1772

    
1773
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1774
    LANGUAGE sql
1775
    AS $_$
1776
-- newline before and after to visually separate it from other debug info
1777
SELECT COALESCE($$
1778
EXPLAIN:
1779
$$||util.fold_explain_msg(util.explain2str($1))||$$
1780
$$, '')
1781
$_$;
1782

    
1783

    
1784
--
1785
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1786
--
1787

    
1788
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1789
    LANGUAGE plpgsql
1790
    AS $$
1791
BEGIN
1792
	RETURN util.explain2notice_msg(sql);
1793
EXCEPTION
1794
WHEN   syntax_error
1795
	OR invalid_cursor_definition -- "cannot open multi-query plan as cursor"
1796
	THEN RETURN NULL; -- non-explainable query
1797
	/* don't use util.is_explainable() because the list provided by Postgres
1798
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1799
	excludes some query types that are in fact EXPLAIN-able */
1800
END;
1801
$$;
1802

    
1803

    
1804
--
1805
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1806
--
1807

    
1808
CREATE FUNCTION explain2str(sql text) RETURNS text
1809
    LANGUAGE sql
1810
    AS $_$
1811
SELECT util.join_strs(explain, $$
1812
$$) FROM util.explain($1)
1813
$_$;
1814

    
1815

    
1816
SET default_tablespace = '';
1817

    
1818
SET default_with_oids = false;
1819

    
1820
--
1821
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1822
--
1823

    
1824
CREATE TABLE explain (
1825
    line text NOT NULL
1826
);
1827

    
1828

    
1829
--
1830
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1831
--
1832

    
1833
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1834
    LANGUAGE sql
1835
    AS $_$
1836
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1837
$$||quote_nullable($1)||$$
1838
)$$)
1839
$_$;
1840

    
1841

    
1842
--
1843
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1844
--
1845

    
1846
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1847
usage:
1848
PERFORM util.explain2table($$
1849
query
1850
$$);
1851
';
1852

    
1853

    
1854
--
1855
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1856
--
1857

    
1858
CREATE FUNCTION first_word(str text) RETURNS text
1859
    LANGUAGE sql IMMUTABLE
1860
    AS $_$
1861
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1862
$_$;
1863

    
1864

    
1865
--
1866
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1867
--
1868

    
1869
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1870
    LANGUAGE sql IMMUTABLE
1871
    AS $_$
1872
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1873
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1874
) END
1875
$_$;
1876

    
1877

    
1878
--
1879
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1880
--
1881

    
1882
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1883
ensures that an array will always have proper non-NULL dimensions
1884
';
1885

    
1886

    
1887
--
1888
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
1889
--
1890

    
1891
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1892
    LANGUAGE sql IMMUTABLE
1893
    AS $_$
1894
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1895
$_$;
1896

    
1897

    
1898
--
1899
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1900
--
1901

    
1902
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1903
    LANGUAGE plpgsql STRICT
1904
    AS $_$
1905
DECLARE
1906
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1907
$$||query;
1908
BEGIN
1909
	EXECUTE mk_view;
1910
EXCEPTION
1911
WHEN invalid_table_definition THEN
1912
	IF SQLERRM = 'cannot drop columns from view'
1913
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1914
	THEN
1915
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1916
		EXECUTE mk_view;
1917
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1918
	END IF;
1919
END;
1920
$_$;
1921

    
1922

    
1923
--
1924
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1925
--
1926

    
1927
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1928
idempotent
1929
';
1930

    
1931

    
1932
--
1933
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1934
--
1935

    
1936
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1937
    LANGUAGE sql STABLE
1938
    AS $_$
1939
SELECT util.eval2val(
1940
$$SELECT NOT EXISTS( -- there is no row that is != 1
1941
	SELECT NULL
1942
	FROM $$||$1||$$
1943
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1944
	LIMIT 1
1945
)
1946
$$, NULL::boolean)
1947
$_$;
1948

    
1949

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

    
1954
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1955
    LANGUAGE sql STABLE
1956
    AS $_$
1957
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1958
$_$;
1959

    
1960

    
1961
--
1962
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1963
--
1964

    
1965
CREATE FUNCTION grants_users() RETURNS SETOF text
1966
    LANGUAGE sql IMMUTABLE
1967
    AS $$
1968
VALUES ('bien_read'), ('public_')
1969
$$;
1970

    
1971

    
1972
--
1973
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1974
--
1975

    
1976
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1977
    LANGUAGE sql IMMUTABLE
1978
    AS $_$
1979
SELECT substring($2 for length($1)) = $1
1980
$_$;
1981

    
1982

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

    
1987
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1988
    LANGUAGE sql STABLE
1989
    AS $_$
1990
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1991
$_$;
1992

    
1993

    
1994
--
1995
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1996
--
1997

    
1998
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1999
    LANGUAGE sql IMMUTABLE
2000
    AS $_$
2001
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
2002
$_$;
2003

    
2004

    
2005
--
2006
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
2007
--
2008

    
2009
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
2010
avoids repeating the same value for each key
2011
';
2012

    
2013

    
2014
--
2015
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2016
--
2017

    
2018
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
2019
    LANGUAGE sql IMMUTABLE
2020
    AS $_$
2021
SELECT COALESCE($1, $2)
2022
$_$;
2023

    
2024

    
2025
--
2026
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
2027
--
2028

    
2029
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
2030
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
2031
';
2032

    
2033

    
2034
--
2035
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
2036
--
2037

    
2038
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
2039
    LANGUAGE sql IMMUTABLE
2040
    AS $_$
2041
SELECT elem FROM unnest($1) elem ORDER BY row_number() OVER () DESC
2042
$_$;
2043

    
2044

    
2045
--
2046
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2047
--
2048

    
2049
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
2050
    LANGUAGE sql
2051
    AS $_$
2052
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
2053
$_$;
2054

    
2055

    
2056
--
2057
-- Name: is_castable(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2058
--
2059

    
2060
CREATE FUNCTION is_castable(value text, ret_type_null anyelement) RETURNS boolean
2061
    LANGUAGE plpgsql IMMUTABLE
2062
    AS $$
2063
BEGIN
2064
	PERFORM util.cast(value, ret_type_null);
2065
	-- must happen *after* cast check, because NULL is not valid for some types
2066
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
2067
	RETURN true;
2068
EXCEPTION
2069
WHEN   data_exception
2070
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
2071
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
2072
	THEN
2073
	RETURN false;
2074
END;
2075
$$;
2076

    
2077

    
2078
--
2079
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
2080
--
2081

    
2082
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
2083
passes NULL through. however, if NULL is not valid for the type, false will be
2084
returned instead.
2085

    
2086
ret_type_null: NULL::ret_type
2087
';
2088

    
2089

    
2090
--
2091
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
2092
--
2093

    
2094
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
2095
    LANGUAGE sql STABLE
2096
    AS $_$
2097
SELECT COALESCE(util.col_comment($1) LIKE '
2098
constant
2099
%', false)
2100
$_$;
2101

    
2102

    
2103
--
2104
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2105
--
2106

    
2107
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
2108
    LANGUAGE sql IMMUTABLE
2109
    AS $_$
2110
SELECT util.array_length($1) = 0
2111
$_$;
2112

    
2113

    
2114
--
2115
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
2116
--
2117

    
2118
CREATE FUNCTION is_explain(sql text) RETURNS boolean
2119
    LANGUAGE sql IMMUTABLE
2120
    AS $_$
2121
SELECT upper(util.first_word($1)) = 'EXPLAIN'
2122
$_$;
2123

    
2124

    
2125
--
2126
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
2127
--
2128

    
2129
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
2130
    LANGUAGE sql IMMUTABLE
2131
    AS $_$
2132
SELECT upper(util.first_word($1)) = ANY(
2133
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
2134
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
2135
)
2136
$_$;
2137

    
2138

    
2139
--
2140
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2141
--
2142

    
2143
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
2144
    LANGUAGE sql IMMUTABLE
2145
    AS $_$
2146
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2147
$_$;
2148

    
2149

    
2150
--
2151
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2152
--
2153

    
2154
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2155
    LANGUAGE sql IMMUTABLE
2156
    AS $_$
2157
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2158
$_$;
2159

    
2160

    
2161
--
2162
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
2163
--
2164

    
2165
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2166
    LANGUAGE sql IMMUTABLE
2167
    AS $_$
2168
SELECT upper(util.first_word($1)) = 'SET'
2169
$_$;
2170

    
2171

    
2172
--
2173
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
2174
--
2175

    
2176
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2177
    LANGUAGE sql STABLE
2178
    AS $_$
2179
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2180
$_$;
2181

    
2182

    
2183
--
2184
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2185
--
2186

    
2187
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2188
    LANGUAGE sql STABLE
2189
    AS $_$
2190
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2191
$_$;
2192

    
2193

    
2194
--
2195
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2196
--
2197

    
2198
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2199
    LANGUAGE sql IMMUTABLE STRICT
2200
    AS $_$
2201
SELECT $1 || $3 || $2
2202
$_$;
2203

    
2204

    
2205
--
2206
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2207
--
2208

    
2209
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2210
must be declared STRICT to use the special handling of STRICT aggregating functions
2211
';
2212

    
2213

    
2214
--
2215
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2216
--
2217

    
2218
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2219
    LANGUAGE sql IMMUTABLE
2220
    AS $_$
2221
SELECT $1 -- compare on the entire value
2222
$_$;
2223

    
2224

    
2225
--
2226
-- Name: keys_eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2227
--
2228

    
2229
CREATE FUNCTION keys_eq(left_ anyelement, right_ anyelement) RETURNS boolean
2230
    LANGUAGE sql STABLE
2231
    AS $_$
2232
SELECT keys($1) = keys($2)
2233
$_$;
2234

    
2235

    
2236
--
2237
-- Name: FUNCTION keys_eq(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
2238
--
2239

    
2240
COMMENT ON FUNCTION keys_eq(left_ anyelement, right_ anyelement) IS '
2241
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**)
2242
';
2243

    
2244

    
2245
--
2246
-- Name: lat_long_in_new_world(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
2247
--
2248

    
2249
CREATE FUNCTION lat_long_in_new_world(latitude_deg double precision, longitude_deg double precision) RETURNS boolean
2250
    LANGUAGE sql IMMUTABLE
2251
    AS $_$
2252
/* use function rather than operator+search_path to allow inlining, which
2253
enables util.new_world() to only be evaluated once */
2254
SELECT util.contained_within(util.point($1, $2), util.new_world())
2255
$_$;
2256

    
2257

    
2258
--
2259
-- Name: FUNCTION lat_long_in_new_world(latitude_deg double precision, longitude_deg double precision); Type: COMMENT; Schema: util; Owner: -
2260
--
2261

    
2262
COMMENT ON FUNCTION lat_long_in_new_world(latitude_deg double precision, longitude_deg double precision) IS '
2263
**WARNING**: this includes false positives above and below the New World
2264
bounding box, as described in util.bounding_box()
2265
';
2266

    
2267

    
2268
--
2269
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2270
--
2271

    
2272
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2273
    LANGUAGE sql IMMUTABLE
2274
    AS $_$
2275
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2276
$_$;
2277

    
2278

    
2279
--
2280
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2281
--
2282

    
2283
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2284
    LANGUAGE plpgsql
2285
    AS $$
2286
DECLARE
2287
	errors_ct integer = 0;
2288
	loop_var loop_type_null%TYPE;
2289
BEGIN
2290
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2291
	LOOP
2292
		BEGIN
2293
			EXECUTE loop_body_sql USING loop_var;
2294
		EXCEPTION
2295
		WHEN OTHERS THEN
2296
			errors_ct = errors_ct+1;
2297
			PERFORM util.raise_error_warning(SQLERRM);
2298
		END;
2299
	END LOOP;
2300
	IF errors_ct > 0 THEN
2301
		-- can't raise exception because this would roll back the transaction
2302
		PERFORM util.raise_error_warning('there were '||errors_ct
2303
			||' errors: see the WARNINGs for details');
2304
	END IF;
2305
END;
2306
$$;
2307

    
2308

    
2309
--
2310
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2311
--
2312

    
2313
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2314
    LANGUAGE sql IMMUTABLE
2315
    AS $_$
2316
SELECT ltrim($1, $$
2317
$$)
2318
$_$;
2319

    
2320

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

    
2325
CREATE FUNCTION map_filter_insert() RETURNS trigger
2326
    LANGUAGE plpgsql
2327
    AS $$
2328
BEGIN
2329
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2330
	RETURN new;
2331
END;
2332
$$;
2333

    
2334

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

    
2339
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2340
    LANGUAGE plpgsql STABLE STRICT
2341
    AS $_$
2342
DECLARE
2343
    value text;
2344
BEGIN
2345
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2346
        INTO value USING key;
2347
    RETURN value;
2348
END;
2349
$_$;
2350

    
2351

    
2352
--
2353
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2354
--
2355

    
2356
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2357
    LANGUAGE sql IMMUTABLE
2358
    AS $_$
2359
SELECT util._map(util.nulls_map($1), $2)
2360
$_$;
2361

    
2362

    
2363
--
2364
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2365
--
2366

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

    
2370
[1] inlining of function calls, which is different from constant folding
2371
[2] _map()''s profiling query
2372
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2373
and map_nulls()''s profiling query
2374
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2375
both take ~920 ms.
2376
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.
2377
';
2378

    
2379

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

    
2384
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2385
    LANGUAGE plpgsql STABLE STRICT
2386
    AS $_$
2387
BEGIN
2388
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2389
END;
2390
$_$;
2391

    
2392

    
2393
--
2394
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2395
--
2396

    
2397
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2398
    LANGUAGE sql
2399
    AS $_$
2400
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2401
$$||util.ltrim_nl($2));
2402
-- make sure the created table has the correct estimated row count
2403
SELECT util.analyze_($1);
2404

    
2405
SELECT util.append_comment($1, '
2406
contents generated from:
2407
'||util.ltrim_nl(util.runnable_sql($2))||';
2408
');
2409
$_$;
2410

    
2411

    
2412
--
2413
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2414
--
2415

    
2416
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2417
idempotent
2418
';
2419

    
2420

    
2421
--
2422
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2423
--
2424

    
2425
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2426
    LANGUAGE sql
2427
    AS $_$
2428
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2429
$_$;
2430

    
2431

    
2432
--
2433
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2434
--
2435

    
2436
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2437
idempotent
2438
';
2439

    
2440

    
2441
--
2442
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2443
--
2444

    
2445
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2446
    LANGUAGE sql
2447
    AS $_$
2448
SELECT util.create_if_not_exists($$
2449
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2450
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2451
||quote_literal($2)||$$;
2452
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2453
constant
2454
';
2455
$$)
2456
$_$;
2457

    
2458

    
2459
--
2460
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2461
--
2462

    
2463
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2464
idempotent
2465
';
2466

    
2467

    
2468
--
2469
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2470
--
2471

    
2472
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2473
    LANGUAGE plpgsql STRICT
2474
    AS $_$
2475
DECLARE
2476
    type regtype = util.typeof(expr, col.table_::text::regtype);
2477
    col_name_sql text = quote_ident(col.name);
2478
BEGIN
2479
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2480
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2481
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2482
$$||expr||$$;
2483
$$);
2484
END;
2485
$_$;
2486

    
2487

    
2488
--
2489
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2490
--
2491

    
2492
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2493
idempotent
2494
';
2495

    
2496

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

    
2501
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
2502
    LANGUAGE sql IMMUTABLE
2503
    AS $_$
2504
SELECT
2505
$$SELECT
2506
$$||$3||$$
2507
FROM      $$||$1||$$ left_
2508
FULL JOIN $$||$2||$$ right_
2509
ON $$||$4||$$
2510
WHERE $$||$5||$$
2511
ORDER BY left_, right_
2512
$$
2513
$_$;
2514

    
2515

    
2516
--
2517
-- Name: mk_drop_from_create(text); Type: FUNCTION; Schema: util; Owner: -
2518
--
2519

    
2520
CREATE FUNCTION mk_drop_from_create(create_cmd text) RETURNS text
2521
    LANGUAGE sql IMMUTABLE
2522
    AS $_$
2523
SELECT $$DROP $$||(util.regexp_match($1,
2524
-- match first CREATE, *if* no DROP came before it
2525
'(?m)\A(?:^(?!DROP\y).*\n)*?^CREATE(?: OR REPLACE)? ((?:)??[[:upper:]]+ .*?)(?: AS(?: (?:SELECT\y.*)?)?)?$'
2526
	/* (?:)?? makes the surrounding () group non-greedy, so that (?: AS ?)?
2527
	works properly (due to nonstandard Postgres regexp behavior:
2528
	http://www.postgresql.org/docs/9.3/static/functions-matching.html#POSIX-MATCHING-RULES) */
2529
))[1]||$$;$$
2530
$_$;
2531

    
2532

    
2533
--
2534
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2535
--
2536

    
2537
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2538
    LANGUAGE sql
2539
    AS $_$
2540
-- keys()
2541
SELECT util.mk_keys_func($1, ARRAY(
2542
SELECT col FROM util.typed_cols($1) col
2543
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2544
));
2545

    
2546
-- values_()
2547
SELECT util.mk_keys_func($1, COALESCE(
2548
	NULLIF(ARRAY(
2549
	SELECT col FROM util.typed_cols($1) col
2550
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2551
	), ARRAY[]::util.col_cast[])
2552
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2553
, 'values_');
2554
$_$;
2555

    
2556

    
2557
--
2558
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2559
--
2560

    
2561
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2562
    LANGUAGE sql
2563
    AS $_$
2564
SELECT util.create_if_not_exists($$
2565
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2566
($$||util.mk_typed_cols_list($2)||$$);
2567
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2568
autogenerated
2569
';
2570
$$);
2571

    
2572
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2573
$_$;
2574

    
2575

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

    
2580
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2581
    LANGUAGE sql
2582
    AS $_$
2583
SELECT util.create_if_not_exists($$
2584
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2585
||util.qual_name($1)||$$)
2586
  RETURNS $$||util.qual_name($2)||$$ AS
2587
$BODY1$
2588
SELECT ROW($$||
2589
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2590
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2591
$BODY1$
2592
  LANGUAGE sql IMMUTABLE
2593
  COST 100;
2594
$$);
2595
$_$;
2596

    
2597

    
2598
--
2599
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2600
--
2601

    
2602
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2603
    LANGUAGE sql
2604
    AS $_$
2605
SELECT util.create_if_not_exists($$
2606
CREATE TABLE $$||$1||$$
2607
(
2608
    LIKE util.map INCLUDING ALL
2609
);
2610

    
2611
CREATE TRIGGER map_filter_insert
2612
  BEFORE INSERT
2613
  ON $$||$1||$$
2614
  FOR EACH ROW
2615
  EXECUTE PROCEDURE util.map_filter_insert();
2616
$$)
2617
$_$;
2618

    
2619

    
2620
--
2621
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2622
--
2623

    
2624
CREATE FUNCTION mk_not_null(text) RETURNS text
2625
    LANGUAGE sql IMMUTABLE
2626
    AS $_$
2627
SELECT COALESCE($1, '<NULL>')
2628
$_$;
2629

    
2630

    
2631
--
2632
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2633
--
2634

    
2635
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2636
    LANGUAGE sql IMMUTABLE
2637
    AS $_$
2638
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2639
util.qual_name((unnest).type), ''), '')
2640
FROM unnest($1)
2641
$_$;
2642

    
2643

    
2644
--
2645
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2646
--
2647

    
2648
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2649
    LANGUAGE sql IMMUTABLE
2650
    AS $_$
2651
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2652
$_$;
2653

    
2654

    
2655
--
2656
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2657
--
2658

    
2659
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2660
auto-appends util to the search_path to enable use of util operators
2661
';
2662

    
2663

    
2664
--
2665
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2666
--
2667

    
2668
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2669
    LANGUAGE sql STABLE
2670
    AS $_$
2671
SELECT COALESCE($$COMMENT ON $$||util.relation_type($1)||$$ $$||$1||$$ IS $$
2672
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2673
$_$;
2674

    
2675

    
2676
--
2677
-- Name: mk_set_relation_metadata(regclass); Type: FUNCTION; Schema: util; Owner: -
2678
--
2679

    
2680
CREATE FUNCTION mk_set_relation_metadata(relation regclass) RETURNS text
2681
    LANGUAGE sql STABLE
2682
    AS $_$
2683
SELECT util.show_grants_for($1)
2684
||util.show_set_comment($1)||$$
2685
$$
2686
$_$;
2687

    
2688

    
2689
--
2690
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2691
--
2692

    
2693
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2694
    LANGUAGE sql IMMUTABLE
2695
    AS $_$
2696
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2697
$_$;
2698

    
2699

    
2700
--
2701
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2702
--
2703

    
2704
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2705
    LANGUAGE sql IMMUTABLE
2706
    AS $_$
2707
/* debug_print_return_value() needed because this function is used with EXECUTE
2708
rather than util.eval() (in order to affect the calling function), so the
2709
search_path would not otherwise be printed */
2710
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2711
||$$ search_path TO $$||$1
2712
$_$;
2713

    
2714

    
2715
--
2716
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2717
--
2718

    
2719
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2720
    LANGUAGE sql
2721
    AS $_$
2722
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2723
$_$;
2724

    
2725

    
2726
--
2727
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2728
--
2729

    
2730
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2731
idempotent
2732
';
2733

    
2734

    
2735
--
2736
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2737
--
2738

    
2739
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2740
    LANGUAGE plpgsql STRICT
2741
    AS $_$
2742
DECLARE
2743
	view_qual_name text = util.qual_name(view_);
2744
BEGIN
2745
	EXECUTE $$
2746
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2747
  RETURNS SETOF $$||view_||$$ AS
2748
$BODY1$
2749
SELECT * FROM $$||view_qual_name||$$
2750
ORDER BY sort_col
2751
LIMIT $1 OFFSET $2
2752
$BODY1$
2753
  LANGUAGE sql STABLE
2754
  COST 100
2755
  ROWS 1000
2756
$$;
2757
	
2758
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2759
END;
2760
$_$;
2761

    
2762

    
2763
--
2764
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2765
--
2766

    
2767
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2768
    LANGUAGE plpgsql STRICT
2769
    AS $_$
2770
DECLARE
2771
	view_qual_name text = util.qual_name(view_);
2772
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2773
BEGIN
2774
	EXECUTE $$
2775
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2776
  RETURNS integer AS
2777
$BODY1$
2778
SELECT $$||quote_ident(row_num_col)||$$
2779
FROM $$||view_qual_name||$$
2780
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2781
LIMIT 1
2782
$BODY1$
2783
  LANGUAGE sql STABLE
2784
  COST 100;
2785
$$;
2786
	
2787
	EXECUTE $$
2788
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2789
  RETURNS SETOF $$||view_||$$ AS
2790
$BODY1$
2791
SELECT * FROM $$||view_qual_name||$$
2792
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2793
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2794
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2795
ORDER BY $$||quote_ident(row_num_col)||$$
2796
$BODY1$
2797
  LANGUAGE sql STABLE
2798
  COST 100
2799
  ROWS 1000
2800
$$;
2801
	
2802
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2803
END;
2804
$_$;
2805

    
2806

    
2807
--
2808
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2809
--
2810

    
2811
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2812
    LANGUAGE plpgsql STRICT
2813
    AS $_$
2814
DECLARE
2815
	view_qual_name text = util.qual_name(view_);
2816
BEGIN
2817
	EXECUTE $$
2818
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2819
  RETURNS SETOF $$||view_||$$
2820
  SET enable_sort TO 'off'
2821
  AS
2822
$BODY1$
2823
SELECT * FROM $$||view_qual_name||$$($2, $3)
2824
$BODY1$
2825
  LANGUAGE sql STABLE
2826
  COST 100
2827
  ROWS 1000
2828
;
2829
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2830
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2831
If you want to run EXPLAIN and get expanded output, use the regular subset
2832
function instead. (When a config param is set on a function, EXPLAIN produces
2833
just a function scan.)
2834
';
2835
$$;
2836
END;
2837
$_$;
2838

    
2839

    
2840
--
2841
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2842
--
2843

    
2844
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2845
creates subset function which turns off enable_sort
2846
';
2847

    
2848

    
2849
--
2850
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2851
--
2852

    
2853
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2854
    LANGUAGE sql IMMUTABLE
2855
    AS $_$
2856
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2857
util.qual_name((unnest).type), ', '), '')
2858
FROM unnest($1)
2859
$_$;
2860

    
2861

    
2862
--
2863
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2864
--
2865

    
2866
CREATE FUNCTION name(table_ regclass) RETURNS text
2867
    LANGUAGE sql STABLE
2868
    AS $_$
2869
SELECT relname::text FROM pg_class WHERE oid = $1
2870
$_$;
2871

    
2872

    
2873
--
2874
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2875
--
2876

    
2877
CREATE FUNCTION name(type regtype) RETURNS text
2878
    LANGUAGE sql STABLE
2879
    AS $_$
2880
SELECT typname::text FROM pg_type WHERE oid = $1
2881
$_$;
2882

    
2883

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

    
2888
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2889
    LANGUAGE sql IMMUTABLE
2890
    AS $_$
2891
SELECT octet_length($1) >= util.namedatalen() - $2
2892
$_$;
2893

    
2894

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

    
2899
CREATE FUNCTION namedatalen() RETURNS integer
2900
    LANGUAGE sql IMMUTABLE
2901
    AS $$
2902
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2903
$$;
2904

    
2905

    
2906
--
2907
-- Name: new_world(); Type: FUNCTION; Schema: util; Owner: -
2908
--
2909

    
2910
CREATE FUNCTION new_world() RETURNS postgis.geography
2911
    LANGUAGE sql IMMUTABLE
2912
    SET search_path TO util
2913
    AS $$
2914
SELECT util.bounding_box(-56 ~ 83, 172 ~ -34)
2915
$$;
2916

    
2917

    
2918
--
2919
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2920
--
2921

    
2922
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2923
    LANGUAGE sql IMMUTABLE
2924
    AS $_$
2925
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2926
$_$;
2927

    
2928

    
2929
--
2930
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2931
--
2932

    
2933
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2934
    LANGUAGE sql IMMUTABLE
2935
    AS $_$
2936
SELECT $1 IS NOT NULL
2937
$_$;
2938

    
2939

    
2940
--
2941
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2942
--
2943

    
2944
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2945
    LANGUAGE sql IMMUTABLE
2946
    AS $_$
2947
SELECT util.hstore($1, NULL) || '*=>*'
2948
$_$;
2949

    
2950

    
2951
--
2952
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2953
--
2954

    
2955
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2956
for use with _map()
2957
';
2958

    
2959

    
2960
--
2961
-- Name: numrange(range); Type: FUNCTION; Schema: util; Owner: -
2962
--
2963

    
2964
CREATE FUNCTION numrange(value range) RETURNS numrange
2965
    LANGUAGE sql IMMUTABLE
2966
    AS $_$
2967
SELECT numrange($1.lower, $1.upper, $1.bounds)
2968
$_$;
2969

    
2970

    
2971
--
2972
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2973
--
2974

    
2975
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2976
    LANGUAGE sql IMMUTABLE
2977
    AS $_$
2978
SELECT $2 + COALESCE($1, 0)
2979
$_$;
2980

    
2981

    
2982
--
2983
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2984
--
2985

    
2986
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2987
    LANGUAGE sql STABLE
2988
    AS $_$
2989
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2990
$_$;
2991

    
2992

    
2993
--
2994
-- Name: pg_get_viewdef(regclass); Type: FUNCTION; Schema: util; Owner: -
2995
--
2996

    
2997
CREATE FUNCTION pg_get_viewdef(view_ regclass) RETURNS text
2998
    LANGUAGE sql STABLE
2999
    AS $_$
3000
SELECT util.view_def_to_orig(pg_catalog.pg_get_viewdef($1))
3001
$_$;
3002

    
3003

    
3004
--
3005
-- Name: point(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
3006
--
3007

    
3008
CREATE FUNCTION point(latitude_deg double precision, longitude_deg double precision) RETURNS postgis.geography
3009
    LANGUAGE sql IMMUTABLE
3010
    SET client_min_messages TO 'warning'
3011
    AS $_$
3012
SELECT postgis.st_setsrid(postgis.st_point(/*x_lon=*/$2, /*y_lat=*/$1),
3013
/*WGS84*/4326)::postgis.geography
3014
$_$;
3015

    
3016

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

    
3021
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
3022
    LANGUAGE sql
3023
    AS $_$
3024
SELECT util.eval($$INSERT INTO $$||$1||$$
3025
$$||util.ltrim_nl($2));
3026
-- make sure the created table has the correct estimated row count
3027
SELECT util.analyze_($1);
3028
$_$;
3029

    
3030

    
3031
--
3032
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
3033
--
3034

    
3035
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
3036
    LANGUAGE sql IMMUTABLE
3037
    AS $_$
3038
SELECT util.qual_name(util.schema($2), $1||util.name($2))
3039
$_$;
3040

    
3041

    
3042
--
3043
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3044
--
3045

    
3046
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
3047
    LANGUAGE sql
3048
    AS $_$
3049
SELECT util.set_comment($1, concat($2, util.comment($1)))
3050
$_$;
3051

    
3052

    
3053
--
3054
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
3055
--
3056

    
3057
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
3058
comment: must start and end with a newline
3059
';
3060

    
3061

    
3062
--
3063
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
3064
--
3065

    
3066
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
3067
    LANGUAGE sql IMMUTABLE
3068
    AS $_$
3069
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
3070
$_$;
3071

    
3072

    
3073
--
3074
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
3075
--
3076

    
3077
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
3078
    LANGUAGE sql STABLE
3079
    SET search_path TO pg_temp
3080
    AS $_$
3081
SELECT $1::text
3082
$_$;
3083

    
3084

    
3085
--
3086
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
3087
--
3088

    
3089
CREATE FUNCTION qual_name(type regtype) RETURNS text
3090
    LANGUAGE sql STABLE
3091
    SET search_path TO pg_temp
3092
    AS $_$
3093
SELECT $1::text
3094
$_$;
3095

    
3096

    
3097
--
3098
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
3099
--
3100

    
3101
COMMENT ON FUNCTION qual_name(type regtype) IS '
3102
a type''s schema-qualified name
3103
';
3104

    
3105

    
3106
--
3107
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
3108
--
3109

    
3110
CREATE FUNCTION qual_name(type unknown) RETURNS text
3111
    LANGUAGE sql STABLE
3112
    AS $_$
3113
SELECT util.qual_name($1::text::regtype)
3114
$_$;
3115

    
3116

    
3117
--
3118
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
3119
--
3120

    
3121
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
3122
    LANGUAGE sql IMMUTABLE
3123
    AS $_$
3124
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
3125
$_$;
3126

    
3127

    
3128
--
3129
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3130
--
3131

    
3132
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
3133
    LANGUAGE sql IMMUTABLE
3134
    AS $_$
3135
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
3136
$_$;
3137

    
3138

    
3139
--
3140
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
3141
--
3142

    
3143
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
3144
    LANGUAGE sql IMMUTABLE
3145
    AS $_$
3146
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
3147
$_$;
3148

    
3149

    
3150
--
3151
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
3152
--
3153

    
3154
CREATE FUNCTION raise(type text, msg text) RETURNS void
3155
    LANGUAGE sql IMMUTABLE
3156
    AS $_X$
3157
SELECT util.eval($$
3158
CREATE OR REPLACE FUNCTION pg_temp.__raise()
3159
  RETURNS void AS
3160
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
3161
$__BODY1$
3162
BEGIN
3163
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
3164
END;
3165
$__BODY1$
3166
  LANGUAGE plpgsql IMMUTABLE
3167
  COST 100;
3168
$$, verbose_ := false);
3169

    
3170
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
3171
$_X$;
3172

    
3173

    
3174
--
3175
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
3176
--
3177

    
3178
COMMENT ON FUNCTION raise(type text, msg text) IS '
3179
type: a log level from
3180
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
3181
or a condition name from
3182
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
3183
';
3184

    
3185

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

    
3190
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3191
    LANGUAGE sql IMMUTABLE
3192
    AS $_$
3193
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3194
$_$;
3195

    
3196

    
3197
--
3198
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3199
--
3200

    
3201
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3202
    LANGUAGE plpgsql IMMUTABLE STRICT
3203
    AS $$
3204
BEGIN
3205
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3206
END;
3207
$$;
3208

    
3209

    
3210
--
3211
-- Name: range(numeric, numeric); Type: FUNCTION; Schema: util; Owner: -
3212
--
3213

    
3214
CREATE FUNCTION range(lower numeric, upper numeric) RETURNS range
3215
    LANGUAGE sql IMMUTABLE
3216
    AS $_$
3217
SELECT ($1, $2, '[]')::util.range
3218
$_$;
3219

    
3220

    
3221
--
3222
-- Name: recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3223
--
3224

    
3225
CREATE FUNCTION recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
3226
    LANGUAGE plpgsql
3227
    AS $_$
3228
DECLARE
3229
	PG_EXCEPTION_DETAIL text;
3230
	restore_views_info util.restore_views_info;
3231
BEGIN
3232
	restore_views_info = util.save_drop_views(users);
3233
	
3234
	-- trigger the dependent_objects_still_exist exception
3235
	PERFORM util.eval(COALESCE(util.mk_drop_from_create(cmd), '')||cmd);
3236
		-- *not* CASCADE; it must trigger an exception
3237
	
3238
	PERFORM util.restore_views(restore_views_info);
3239
EXCEPTION
3240
WHEN dependent_objects_still_exist THEN
3241
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
3242
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
3243
	users = array(SELECT * FROM util.regexp_matches_group(
3244
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$'));
3245
		-- will be in forward dependency order
3246
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
3247
	PERFORM util.debug_print_var('users', users);
3248
	IF util.is_empty(users) THEN RAISE; END IF;
3249
	PERFORM util.recreate(cmd, users);
3250
END;
3251
$_$;
3252

    
3253

    
3254
--
3255
-- Name: FUNCTION recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
3256
--
3257

    
3258
COMMENT ON FUNCTION recreate(cmd text, users text[]) IS '
3259
the appropriate drop statement will be added automatically.
3260

    
3261
usage:
3262
SELECT util.recreate($$
3263
CREATE VIEW schema.main_view AS _;
3264

    
3265
-- manually restore views that need to be updated for the changes
3266
CREATE VIEW schema.dependent_view AS _;
3267
$$);
3268

    
3269
idempotent
3270

    
3271
users: not necessary to provide this because it will be autopopulated
3272
';
3273

    
3274

    
3275
--
3276
-- Name: recreate_view(regclass, text, text); Type: FUNCTION; Schema: util; Owner: -
3277
--
3278

    
3279
CREATE FUNCTION recreate_view(view_ regclass, view_query text DEFAULT NULL::text, dependent_view_changes text DEFAULT ''::text) RETURNS void
3280
    LANGUAGE sql
3281
    AS $_$
3282
SELECT util.recreate($$
3283
CREATE VIEW $$||$1||$$ AS 
3284
$$||COALESCE($2, pg_get_viewdef($1))||$$;
3285
$$||util.mk_set_relation_metadata($1)||$$
3286

    
3287
-- manually restore views that need to be updated for the changes
3288
$$||$3||$$
3289
$$);
3290
$_$;
3291

    
3292

    
3293
--
3294
-- Name: FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text); Type: COMMENT; Schema: util; Owner: -
3295
--
3296

    
3297
COMMENT ON FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text) IS '
3298
usage:
3299
SELECT util.recreate_view(''schema.main_view'', $$
3300
SELECT __
3301
$$, $$
3302
CREATE VIEW schema.dependent_view AS 
3303
__;
3304
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3305
$$);
3306

    
3307
if view has already been modified:
3308
SELECT util.recreate_view(''schema.main_view'', dependent_view_changes := $$
3309
CREATE VIEW schema.dependent_view AS 
3310
__;
3311
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3312
$$);
3313

    
3314
idempotent
3315
';
3316

    
3317

    
3318
--
3319
-- Name: regexp_match(text, text); Type: FUNCTION; Schema: util; Owner: -
3320
--
3321

    
3322
CREATE FUNCTION regexp_match(str text, re text) RETURNS text[]
3323
    LANGUAGE sql IMMUTABLE
3324
    AS $_$
3325
SELECT match FROM regexp_matches($1, $2) match LIMIT 1/*only 1st match*/
3326
$_$;
3327

    
3328

    
3329
--
3330
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3331
--
3332

    
3333
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3334
    LANGUAGE sql IMMUTABLE
3335
    AS $_$
3336
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3337
$_$;
3338

    
3339

    
3340
--
3341
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3342
--
3343

    
3344
CREATE FUNCTION regexp_quote(str text) RETURNS text
3345
    LANGUAGE sql IMMUTABLE
3346
    AS $_$
3347
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3348
$_$;
3349

    
3350

    
3351
--
3352
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
3353
--
3354

    
3355
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3356
    LANGUAGE sql IMMUTABLE
3357
    AS $_$
3358
SELECT (CASE WHEN right($1, 1) = ')'
3359
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3360
$_$;
3361

    
3362

    
3363
--
3364
-- Name: relation_exists(text); Type: FUNCTION; Schema: util; Owner: -
3365
--
3366

    
3367
CREATE FUNCTION relation_exists(relation text) RETURNS boolean
3368
    LANGUAGE sql STABLE
3369
    AS $_$
3370
SELECT $1 IS NOT NULL AND util.is_castable($1, NULL::regclass)
3371
$_$;
3372

    
3373

    
3374
--
3375
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3376
--
3377

    
3378
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3379
    LANGUAGE sql STABLE
3380
    AS $_$
3381
SELECT util.relation_type(util.relation_type_char($1))
3382
$_$;
3383

    
3384

    
3385
--
3386
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3387
--
3388

    
3389
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3390
    LANGUAGE sql IMMUTABLE
3391
    AS $_$
3392
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3393
$_$;
3394

    
3395

    
3396
--
3397
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3398
--
3399

    
3400
CREATE FUNCTION relation_type(type regtype) RETURNS text
3401
    LANGUAGE sql IMMUTABLE
3402
    AS $$
3403
SELECT 'TYPE'::text
3404
$$;
3405

    
3406

    
3407
--
3408
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
3409
--
3410

    
3411
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3412
    LANGUAGE sql STABLE
3413
    AS $_$
3414
SELECT relkind FROM pg_class WHERE oid = $1
3415
$_$;
3416

    
3417

    
3418
--
3419
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
3420
--
3421

    
3422
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3423
    LANGUAGE sql
3424
    AS $_$
3425
/* can't have in_table/out_table inherit from *each other*, because inheritance
3426
also causes the rows of the parent table to be included in the child table.
3427
instead, they need to inherit from a common, empty table. */
3428
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3429
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3430
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3431
SELECT util.inherit($2, $4);
3432
SELECT util.inherit($3, $4);
3433

    
3434
SELECT util.rematerialize_query($1, $$
3435
SELECT * FROM util.diff(
3436
  $$||util.quote_typed($2)||$$
3437
, $$||util.quote_typed($3)||$$
3438
, NULL::$$||$4||$$)
3439
$$);
3440

    
3441
/* the table unfortunately cannot be *materialized* in human-readable form,
3442
because this would create column name collisions between the two sides */
3443
SELECT util.prepend_comment($1, '
3444
to view this table in human-readable form (with each side''s tuple column
3445
expanded to its component fields):
3446
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3447

    
3448
to display NULL values that are extra or missing:
3449
SELECT * FROM '||$1||';
3450
');
3451
$_$;
3452

    
3453

    
3454
--
3455
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3456
--
3457

    
3458
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3459
type_table (*required*): table to create as the shared base type
3460
';
3461

    
3462

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

    
3467
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3468
    LANGUAGE sql
3469
    AS $_$
3470
SELECT util.drop_table($1);
3471
SELECT util.materialize_query($1, $2);
3472
$_$;
3473

    
3474

    
3475
--
3476
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3477
--
3478

    
3479
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3480
idempotent, but repeats action each time
3481
';
3482

    
3483

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

    
3488
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3489
    LANGUAGE sql
3490
    AS $_$
3491
SELECT util.drop_table($1);
3492
SELECT util.materialize_view($1, $2);
3493
$_$;
3494

    
3495

    
3496
--
3497
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3498
--
3499

    
3500
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3501
idempotent, but repeats action each time
3502
';
3503

    
3504

    
3505
--
3506
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3507
--
3508

    
3509
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3510
    LANGUAGE sql
3511
    AS $_$
3512
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3513
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3514
FROM util.col_names($1::text::regtype) f (name);
3515
SELECT NULL::void; -- don't fold away functions called in previous query
3516
$_$;
3517

    
3518

    
3519
--
3520
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3521
--
3522

    
3523
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3524
idempotent
3525
';
3526

    
3527

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

    
3532
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3533
    LANGUAGE sql
3534
    AS $_$
3535
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3536
included in the debug SQL */
3537
SELECT util.rename_relation(util.qual_name($1), $2)
3538
$_$;
3539

    
3540

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

    
3545
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3546
    LANGUAGE sql
3547
    AS $_$
3548
/* 'ALTER TABLE can be used with views too'
3549
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3550
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3551
||quote_ident($2))
3552
$_$;
3553

    
3554

    
3555
--
3556
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3557
--
3558

    
3559
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3560
idempotent
3561
';
3562

    
3563

    
3564
--
3565
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3566
--
3567

    
3568
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3569
    LANGUAGE sql IMMUTABLE
3570
    AS $_$
3571
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3572
$_$;
3573

    
3574

    
3575
--
3576
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3577
--
3578

    
3579
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3580
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 
3581
';
3582

    
3583

    
3584
--
3585
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3586
--
3587

    
3588
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3589
    LANGUAGE sql
3590
    AS $_$
3591
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3592
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3593
SELECT util.set_col_names($1, $2);
3594
$_$;
3595

    
3596

    
3597
--
3598
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3599
--
3600

    
3601
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3602
idempotent.
3603
alters the names table, so it will need to be repopulated after running this function.
3604
';
3605

    
3606

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

    
3611
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3612
    LANGUAGE sql
3613
    AS $_$
3614
SELECT util.drop_table($1);
3615
SELECT util.mk_map_table($1);
3616
$_$;
3617

    
3618

    
3619
--
3620
-- Name: restore_views(restore_views_info); Type: FUNCTION; Schema: util; Owner: -
3621
--
3622

    
3623
CREATE FUNCTION restore_views(restore_views_info) RETURNS void
3624
    LANGUAGE sql
3625
    AS $_$
3626
SELECT util.debug_print_var('views', $1);
3627
SELECT util.create_if_not_exists((view_).def, (view_).path)
3628
	/* need to specify view name for manual existence check, in case view def
3629
	becomes invalid, which would produce nonstandard (uncatchable) exception */
3630
FROM unnest($1.views) view_; -- in forward dependency order
3631
	/* create_if_not_exists() rather than eval(), because cmd might manually
3632
	re-create a deleted dependent view, causing it to already exist */
3633
SELECT NULL::void; -- don't fold away functions called in previous query
3634
$_$;
3635

    
3636

    
3637
--
3638
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3639
--
3640

    
3641
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3642
    LANGUAGE sql
3643
    AS $_$
3644
SELECT util.drop_column($1, $2, force := true)
3645
$_$;
3646

    
3647

    
3648
--
3649
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3650
--
3651

    
3652
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3653
    LANGUAGE sql IMMUTABLE
3654
    AS $_$
3655
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3656
$_$;
3657

    
3658

    
3659
--
3660
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3661
--
3662

    
3663
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3664
    LANGUAGE sql IMMUTABLE
3665
    AS $_$
3666
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3667
ELSE util.mk_set_search_path(for_printing := true)||$$;
3668
$$ END)||$1
3669
$_$;
3670

    
3671

    
3672
--
3673
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3674
--
3675

    
3676
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3677
    LANGUAGE plpgsql STRICT
3678
    AS $$
3679
DECLARE
3680
	result text = NULL;
3681
BEGIN
3682
	BEGIN
3683
		result = util.show_create_view(view_, replace := false);
3684
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3685
			(eg. invalid_table_definition), instead of the standard
3686
			duplicate_table exception caught by util.create_if_not_exists() */
3687
		PERFORM util.drop_view(view_);
3688
	EXCEPTION
3689
		WHEN undefined_table THEN NULL;
3690
	END;
3691
	RETURN result;
3692
END;
3693
$$;
3694

    
3695

    
3696
--
3697
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3698
--
3699

    
3700
CREATE FUNCTION save_drop_views(views text[]) RETURNS restore_views_info
3701
    LANGUAGE sql
3702
    AS $_$
3703
SELECT ROW(/*return in forward dependency order*/util.array_reverse(array(
3704
SELECT (view_, util.save_drop_view(view_))::util.db_item
3705
FROM unnest(/*drop in reverse dependency order*/util.array_reverse($1)) view_
3706
)))::util.restore_views_info
3707
$_$;
3708

    
3709

    
3710
--
3711
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3712
--
3713

    
3714
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3715
    LANGUAGE sql STABLE
3716
    AS $_$
3717
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3718
$_$;
3719

    
3720

    
3721
--
3722
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3723
--
3724

    
3725
CREATE FUNCTION schema(table_ regclass) RETURNS text
3726
    LANGUAGE sql STABLE
3727
    AS $_$
3728
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3729
$_$;
3730

    
3731

    
3732
--
3733
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3734
--
3735

    
3736
CREATE FUNCTION schema(type regtype) RETURNS text
3737
    LANGUAGE sql STABLE
3738
    AS $_$
3739
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3740
$_$;
3741

    
3742

    
3743
--
3744
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3745
--
3746

    
3747
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3748
    LANGUAGE sql STABLE
3749
    AS $_$
3750
SELECT util.schema(pg_typeof($1))
3751
$_$;
3752

    
3753

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

    
3758
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3759
    LANGUAGE sql STABLE
3760
    AS $_$
3761
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3762
$_$;
3763

    
3764

    
3765
--
3766
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3767
--
3768

    
3769
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3770
a schema bundle is a group of schemas with a common prefix
3771
';
3772

    
3773

    
3774
--
3775
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3776
--
3777

    
3778
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3779
    LANGUAGE sql
3780
    AS $_$
3781
SELECT util.schema_rename(old_schema,
3782
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3783
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3784
SELECT NULL::void; -- don't fold away functions called in previous query
3785
$_$;
3786

    
3787

    
3788
--
3789
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3790
--
3791

    
3792
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3793
    LANGUAGE plpgsql
3794
    AS $$
3795
BEGIN
3796
	-- don't schema_bundle_rm() the schema_bundle to keep!
3797
	IF replace = with_ THEN RETURN; END IF;
3798
	
3799
	PERFORM util.schema_bundle_rm(replace);
3800
	PERFORM util.schema_bundle_rename(with_, replace);
3801
END;
3802
$$;
3803

    
3804

    
3805
--
3806
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3807
--
3808

    
3809
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3810
    LANGUAGE sql
3811
    AS $_$
3812
SELECT util.schema_rm(schema)
3813
FROM util.schema_bundle_get_schemas($1) f (schema);
3814
SELECT NULL::void; -- don't fold away functions called in previous query
3815
$_$;
3816

    
3817

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

    
3822
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3823
    LANGUAGE sql STABLE
3824
    AS $_$
3825
SELECT quote_ident(util.schema($1))
3826
$_$;
3827

    
3828

    
3829
--
3830
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3831
--
3832

    
3833
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3834
    LANGUAGE sql IMMUTABLE
3835
    AS $_$
3836
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3837
$_$;
3838

    
3839

    
3840
--
3841
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3842
--
3843

    
3844
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3845
    LANGUAGE sql STABLE
3846
    AS $_$
3847
SELECT oid FROM pg_namespace WHERE nspname = $1
3848
$_$;
3849

    
3850

    
3851
--
3852
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3853
--
3854

    
3855
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3856
    LANGUAGE sql IMMUTABLE
3857
    AS $_$
3858
SELECT util.schema_regexp(schema_anchor := $1)
3859
$_$;
3860

    
3861

    
3862
--
3863
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3864
--
3865

    
3866
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3867
    LANGUAGE sql IMMUTABLE
3868
    AS $_$
3869
SELECT util.str_equality_regexp(util.schema($1))
3870
$_$;
3871

    
3872

    
3873
--
3874
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3875
--
3876

    
3877
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3878
    LANGUAGE sql
3879
    AS $_$
3880
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3881
$_$;
3882

    
3883

    
3884
--
3885
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3886
--
3887

    
3888
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3889
    LANGUAGE plpgsql
3890
    AS $$
3891
BEGIN
3892
	-- don't schema_rm() the schema to keep!
3893
	IF replace = with_ THEN RETURN; END IF;
3894
	
3895
	PERFORM util.schema_rm(replace);
3896
	PERFORM util.schema_rename(with_, replace);
3897
END;
3898
$$;
3899

    
3900

    
3901
--
3902
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3903
--
3904

    
3905
CREATE FUNCTION schema_rm(schema text) RETURNS void
3906
    LANGUAGE sql
3907
    AS $_$
3908
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3909
$_$;
3910

    
3911

    
3912
--
3913
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3914
--
3915

    
3916
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3917
    LANGUAGE sql
3918
    AS $_$
3919
SELECT util.eval(
3920
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3921
$_$;
3922

    
3923

    
3924
--
3925
-- Name: seq__create(text, integer); Type: FUNCTION; Schema: util; Owner: -
3926
--
3927

    
3928
CREATE FUNCTION seq__create(seq text, start integer DEFAULT 0) RETURNS void
3929
    LANGUAGE sql
3930
    AS $_$
3931
SELECT util.create_if_not_exists($$CREATE SEQUENCE $$||$1||$$ MINVALUE $$||$2,
3932
$1)
3933
$_$;
3934

    
3935

    
3936
--
3937
-- Name: FUNCTION seq__create(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
3938
--
3939

    
3940
COMMENT ON FUNCTION seq__create(seq text, start integer) IS '
3941
idempotent
3942
';
3943

    
3944

    
3945
--
3946
-- Name: seq__reset(text, integer); Type: FUNCTION; Schema: util; Owner: -
3947
--
3948

    
3949
CREATE FUNCTION seq__reset(seq text, start integer DEFAULT 0) RETURNS void
3950
    LANGUAGE sql
3951
    AS $_$
3952
SELECT util.seq__create($1, $2);
3953
SELECT util.eval($$ALTER SEQUENCE $$||$1||$$ RESTART$$);
3954
$_$;
3955

    
3956

    
3957
--
3958
-- Name: FUNCTION seq__reset(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
3959
--
3960

    
3961
COMMENT ON FUNCTION seq__reset(seq text, start integer) IS '
3962
creates sequence if doesn''t exist
3963

    
3964
idempotent
3965

    
3966
start: *note*: only used if sequence doesn''t exist
3967
';
3968

    
3969

    
3970
--
3971
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3972
--
3973

    
3974
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3975
    LANGUAGE plpgsql STRICT
3976
    AS $_$
3977
DECLARE
3978
    old text[] = ARRAY(SELECT util.col_names(table_));
3979
    new text[] = ARRAY(SELECT util.map_values(names));
3980
BEGIN
3981
    old = old[1:array_length(new, 1)]; -- truncate to same length
3982
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3983
||$$ TO $$||quote_ident(value))
3984
    FROM each(hstore(old, new))
3985
    WHERE value != key -- not same name
3986
    ;
3987
END;
3988
$_$;
3989

    
3990

    
3991
--
3992
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3993
--
3994

    
3995
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3996
idempotent
3997
';
3998

    
3999

    
4000
--
4001
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
4002
--
4003

    
4004
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
4005
    LANGUAGE plpgsql STRICT
4006
    AS $_$
4007
DECLARE
4008
	row_ util.map;
4009
BEGIN
4010
	-- rename any metadata cols rather than re-adding them with new names
4011
	BEGIN
4012
		PERFORM util.set_col_names(table_, names);
4013
	EXCEPTION
4014
		WHEN array_subscript_error THEN -- selective suppress
4015
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
4016
				-- metadata cols not yet added
4017
			ELSE RAISE;
4018
			END IF;
4019
	END;
4020
	
4021
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
4022
	LOOP
4023
		PERFORM util.mk_const_col((table_, row_."to"),
4024
			substring(row_."from" from 2));
4025
	END LOOP;
4026
	
4027
	PERFORM util.set_col_names(table_, names);
4028
END;
4029
$_$;
4030

    
4031

    
4032
--
4033
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
4034
--
4035

    
4036
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
4037
idempotent.
4038
the metadata mappings must be *last* in the names table.
4039
';
4040

    
4041

    
4042
--
4043
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
4044
--
4045

    
4046
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
4047
    LANGUAGE sql
4048
    AS $_$
4049
SELECT util.eval(COALESCE(
4050
$$ALTER TABLE $$||$1||$$
4051
$$||(
4052
	SELECT
4053
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
4054
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
4055
, $$)
4056
	FROM
4057
	(
4058
		SELECT
4059
		  quote_ident(col_name) AS col_name_sql
4060
		, util.col_type(($1, col_name)) AS curr_type
4061
		, type AS target_type
4062
		FROM unnest($2)
4063
	) s
4064
	WHERE curr_type != target_type
4065
), ''))
4066
$_$;
4067

    
4068

    
4069
--
4070
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
4071
--
4072

    
4073
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
4074
idempotent
4075
';
4076

    
4077

    
4078
--
4079
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4080
--
4081

    
4082
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
4083
    LANGUAGE sql
4084
    AS $_$
4085
SELECT util.eval(util.mk_set_comment($1, $2))
4086
$_$;
4087

    
4088

    
4089
--
4090
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
4091
--
4092

    
4093
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
4094
    LANGUAGE sql
4095
    AS $_$
4096
SELECT util.eval(util.mk_set_search_path($1, $2))
4097
$_$;
4098

    
4099

    
4100
--
4101
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4102
--
4103

    
4104
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
4105
    LANGUAGE sql STABLE
4106
    AS $_$
4107
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
4108
||$1||$$ AS
4109
$$||util.pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
4110
$$||util.mk_set_relation_metadata($1)
4111
$_$;
4112

    
4113

    
4114
--
4115
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
4116
--
4117

    
4118
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
4119
    LANGUAGE sql STABLE
4120
    AS $_$
4121
SELECT string_agg(cmd, '')
4122
FROM
4123
(
4124
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
4125
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
4126
$$ ELSE '' END) AS cmd
4127
	FROM util.grants_users() f (user_)
4128
) s
4129
$_$;
4130

    
4131

    
4132
--
4133
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
4134
--
4135

    
4136
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
4137
    LANGUAGE sql STABLE
4138
    AS $_$
4139
SELECT oid FROM pg_class
4140
WHERE relkind = ANY($3) AND relname ~ $1
4141
AND util.schema_matches(util.schema(relnamespace), $2)
4142
ORDER BY relname
4143
$_$;
4144

    
4145

    
4146
--
4147
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
4148
--
4149

    
4150
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
4151
    LANGUAGE sql STABLE
4152
    AS $_$
4153
SELECT util.mk_set_comment($1, util.comment($1))
4154
$_$;
4155

    
4156

    
4157
--
4158
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4159
--
4160

    
4161
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
4162
    LANGUAGE sql STABLE
4163
    AS $_$
4164
SELECT oid
4165
FROM pg_type
4166
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
4167
ORDER BY typname
4168
$_$;
4169

    
4170

    
4171
--
4172
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4173
--
4174

    
4175
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
4176
    LANGUAGE sql STABLE
4177
    AS $_$
4178
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
4179
$_$;
4180

    
4181

    
4182
--
4183
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
4184
--
4185

    
4186
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
4187
    LANGUAGE sql IMMUTABLE
4188
    AS $_$
4189
SELECT '^'||util.regexp_quote($1)||'$'
4190
$_$;
4191

    
4192

    
4193
--
4194
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
4195
--
4196

    
4197
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
4198
    LANGUAGE plpgsql STABLE STRICT
4199
    AS $_$
4200
DECLARE
4201
    hstore hstore;
4202
BEGIN
4203
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
4204
        table_||$$))$$ INTO STRICT hstore;
4205
    RETURN hstore;
4206
END;
4207
$_$;
4208

    
4209

    
4210
--
4211
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4212
--
4213

    
4214
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
4215
    LANGUAGE sql STABLE
4216
    AS $_$
4217
SELECT COUNT(*) > 0 FROM pg_constraint
4218
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
4219
$_$;
4220

    
4221

    
4222
--
4223
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4224
--
4225

    
4226
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
4227
gets whether a status flag is set by the presence of a table constraint
4228
';
4229

    
4230

    
4231
--
4232
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4233
--
4234

    
4235
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
4236
    LANGUAGE sql
4237
    AS $_$
4238
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
4239
||quote_ident($2)||$$ CHECK (true)$$)
4240
$_$;
4241

    
4242

    
4243
--
4244
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4245
--
4246

    
4247
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
4248
stores a status flag by the presence of a table constraint.
4249
idempotent.
4250
';
4251

    
4252

    
4253
--
4254
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
4255
--
4256

    
4257
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
4258
    LANGUAGE sql STABLE
4259
    AS $_$
4260
SELECT util.table_flag__get($1, 'nulls_mapped')
4261
$_$;
4262

    
4263

    
4264
--
4265
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4266
--
4267

    
4268
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
4269
gets whether a table''s NULL-equivalent strings have been replaced with NULL
4270
';
4271

    
4272

    
4273
--
4274
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
4275
--
4276

    
4277
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
4278
    LANGUAGE sql
4279
    AS $_$
4280
SELECT util.table_flag__set($1, 'nulls_mapped')
4281
$_$;
4282

    
4283

    
4284
--
4285
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4286
--
4287

    
4288
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
4289
sets that a table''s NULL-equivalent strings have been replaced with NULL.
4290
idempotent.
4291
';
4292

    
4293

    
4294
--
4295
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
4296
--
4297

    
4298
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
4299
    LANGUAGE sql
4300
    AS $_$
4301
-- save data before truncating main table
4302
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
4303

    
4304
-- repopulate main table w/ copies column
4305
SELECT util.truncate($1);
4306
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
4307
SELECT util.populate_table($1, $$
4308
SELECT (table_).*, copies
4309
FROM (
4310
	SELECT table_, COUNT(*) AS copies
4311
	FROM pg_temp.__copy table_
4312
	GROUP BY table_
4313
) s
4314
$$);
4315

    
4316
-- delete temp table so it doesn't stay around until end of connection
4317
SELECT util.drop_table('pg_temp.__copy');
4318
$_$;
4319

    
4320

    
4321
--
4322
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
4323
--
4324

    
4325
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
4326
    LANGUAGE plpgsql STRICT
4327
    AS $_$
4328
DECLARE
4329
    row record;
4330
BEGIN
4331
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
4332
    LOOP
4333
        IF row.global_name != row.name THEN
4334
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
4335
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
4336
        END IF;
4337
    END LOOP;
4338
END;
4339
$_$;
4340

    
4341

    
4342
--
4343
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4344
--
4345

    
4346
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
4347
idempotent
4348
';
4349

    
4350

    
4351
--
4352
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4353
--
4354

    
4355
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
4356
    LANGUAGE sql
4357
    AS $_$
4358
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
4359
SELECT NULL::void; -- don't fold away functions called in previous query
4360
$_$;
4361

    
4362

    
4363
--
4364
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
4365
--
4366

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

    
4370
by default, cascadingly drops dependent columns so that they don''t prevent
4371
trim() from succeeding. note that this requires the dependent columns to then be
4372
manually re-created.
4373

    
4374
idempotent
4375
';
4376

    
4377

    
4378
--
4379
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4380
--
4381

    
4382
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4383
    LANGUAGE plpgsql STRICT
4384
    AS $_$
4385
BEGIN
4386
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4387
END;
4388
$_$;
4389

    
4390

    
4391
--
4392
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4393
--
4394

    
4395
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4396
idempotent
4397
';
4398

    
4399

    
4400
--
4401
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4402
--
4403

    
4404
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4405
    LANGUAGE sql IMMUTABLE
4406
    AS $_$
4407
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4408
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4409
$_$;
4410

    
4411

    
4412
--
4413
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4414
--
4415

    
4416
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4417
    LANGUAGE plpgsql IMMUTABLE
4418
    AS $$
4419
BEGIN
4420
	/* need explicit cast because some types not implicitly-castable, and also
4421
	to make the cast happen inside the try block. (*implicit* casts to the
4422
	return type happen at the end of the function, outside any block.) */
4423
	RETURN util.cast(value, ret_type_null);
4424
EXCEPTION
4425
WHEN   data_exception
4426
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
4427
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
4428
	THEN
4429
	PERFORM util.raise('WARNING', SQLERRM);
4430
	RETURN NULL;
4431
END;
4432
$$;
4433

    
4434

    
4435
--
4436
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4437
--
4438

    
4439
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4440
ret_type_null: NULL::ret_type
4441
';
4442

    
4443

    
4444
--
4445
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4446
--
4447

    
4448
CREATE FUNCTION try_create(sql text) RETURNS void
4449
    LANGUAGE plpgsql STRICT
4450
    AS $$
4451
BEGIN
4452
	PERFORM util.eval(sql);
4453
EXCEPTION
4454
WHEN   not_null_violation
4455
		/* trying to add NOT NULL column to parent table, which cascades to
4456
		child table whose values for the new column will be NULL */
4457
	OR wrong_object_type -- trying to alter a view's columns
4458
	OR undefined_column
4459
	OR duplicate_column
4460
THEN NULL;
4461
WHEN datatype_mismatch THEN
4462
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4463
	ELSE RAISE; -- rethrow
4464
	END IF;
4465
END;
4466
$$;
4467

    
4468

    
4469
--
4470
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4471
--
4472

    
4473
COMMENT ON FUNCTION try_create(sql text) IS '
4474
idempotent
4475
';
4476

    
4477

    
4478
--
4479
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4480
--
4481

    
4482
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4483
    LANGUAGE sql
4484
    AS $_$
4485
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4486
$_$;
4487

    
4488

    
4489
--
4490
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4491
--
4492

    
4493
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4494
idempotent
4495
';
4496

    
4497

    
4498
--
4499
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4500
--
4501

    
4502
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4503
    LANGUAGE sql IMMUTABLE
4504
    AS $_$
4505
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4506
$_$;
4507

    
4508

    
4509
--
4510
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4511
--
4512

    
4513
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4514
a type''s NOT NULL qualifier
4515
';
4516

    
4517

    
4518
--
4519
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4520
--
4521

    
4522
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4523
    LANGUAGE sql STABLE
4524
    AS $_$
4525
SELECT (attname::text, atttypid)::util.col_cast
4526
FROM pg_attribute
4527
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4528
ORDER BY attnum
4529
$_$;
4530

    
4531

    
4532
--
4533
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4534
--
4535

    
4536
CREATE FUNCTION typeof(value anyelement) RETURNS text
4537
    LANGUAGE sql IMMUTABLE
4538
    AS $_$
4539
SELECT util.qual_name(pg_typeof($1))
4540
$_$;
4541

    
4542

    
4543
--
4544
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4545
--
4546

    
4547
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4548
    LANGUAGE plpgsql STABLE
4549
    AS $_$
4550
DECLARE
4551
    type regtype;
4552
BEGIN
4553
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4554
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4555
    RETURN type;
4556
END;
4557
$_$;
4558

    
4559

    
4560
--
4561
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4562
--
4563

    
4564
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4565
    LANGUAGE sql
4566
    AS $_$
4567
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4568
$_$;
4569

    
4570

    
4571
--
4572
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4573
--
4574

    
4575
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4576
auto-appends util to the search_path to enable use of util operators
4577
';
4578

    
4579

    
4580
--
4581
-- Name: view_def_to_orig(text); Type: FUNCTION; Schema: util; Owner: -
4582
--
4583

    
4584
CREATE FUNCTION view_def_to_orig(view_def text) RETURNS text
4585
    LANGUAGE sql IMMUTABLE
4586
    AS $_$
4587
SELECT CASE
4588
WHEN util.view_is_subset($1) THEN $1
4589
	-- list of cols from the same table is not an expanded * expression
4590
ELSE
4591
regexp_replace(
4592
regexp_replace(
4593
$1
4594
,
4595
/* unexpand expanded * expressions. any list of 6+ cols from the same table is
4596
treated as a * expression. */
4597
'((?:"[^"\s]+"|\w+)\.)(?:"[^"\s]+"|\w+)'||
4598
	/* 1st col, which lacks separator before.
4599
	*note*: can't prepend \y because it considers only \w chars, not " */
4600
'(,[[:blank:]]*
4601
[[:blank:]]*)\1(?:"[^"\s]+"|\w+)'|| -- 2nd col, which has separator before
4602
'(?:\2\1(?:"[^"\s]+"|\w+)){4,}', -- later cols, w/ same table name and separator
4603
'\1*'/*prefix w/ table*/,
4604
'g')
4605
,
4606
/* merge .* expressions resulting from a SELECT * of a join. any list of
4607
multiple .* expressions is treated as a SELECT * . */
4608
'(?:"[^"\s]+"|\w+)\.\*'||
4609
	/* 1st table, which lacks separator before.
4610
	*note*: can't prepend \y because it considers only \w chars, not " */
4611
'(,[[:blank:]]*
4612
[[:blank:]]*)(?:"[^"\s]+"|\w+)\.\*'|| -- 2nd table, which has separator before
4613
'(?:\1(?:"[^"\s]+"|\w+)\.\*)*', -- later tables, w/ same separator
4614
'*',
4615
'g')
4616
END
4617
$_$;
4618

    
4619

    
4620
--
4621
-- Name: view_is_automatically_updatable(text); Type: FUNCTION; Schema: util; Owner: -
4622
--
4623

    
4624
CREATE FUNCTION view_is_automatically_updatable(view_def text) RETURNS boolean
4625
    LANGUAGE sql IMMUTABLE
4626
    AS $_$
4627
SELECT $1 !~ '\y(?:JOIN|WITH|DISTINCT|GROUP BY|HAVING|LIMIT|OFFSET)\y'
4628
	/* from http://www.postgresql.org/docs/9.3/static/sql-createview.html#SQL-CREATEVIEW-UPDATABLE-VIEWS */
4629
$_$;
4630

    
4631

    
4632
--
4633
-- Name: view_is_subset(text); Type: FUNCTION; Schema: util; Owner: -
4634
--
4635

    
4636
CREATE FUNCTION view_is_subset(view_def text) RETURNS boolean
4637
    LANGUAGE sql IMMUTABLE
4638
    AS $_$
4639
SELECT util.view_is_automatically_updatable($1)
4640
$_$;
4641

    
4642

    
4643
--
4644
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4645
--
4646

    
4647
CREATE AGGREGATE all_same(anyelement) (
4648
    SFUNC = all_same_transform,
4649
    STYPE = anyarray,
4650
    FINALFUNC = all_same_final
4651
);
4652

    
4653

    
4654
--
4655
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4656
--
4657

    
4658
COMMENT ON AGGREGATE all_same(anyelement) IS '
4659
includes NULLs in comparison
4660
';
4661

    
4662

    
4663
--
4664
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4665
--
4666

    
4667
CREATE AGGREGATE join_strs(text, text) (
4668
    SFUNC = join_strs_transform,
4669
    STYPE = text
4670
);
4671

    
4672

    
4673
--
4674
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4675
--
4676

    
4677
CREATE OPERATOR %== (
4678
    PROCEDURE = keys_eq,
4679
    LEFTARG = anyelement,
4680
    RIGHTARG = anyelement
4681
);
4682

    
4683

    
4684
--
4685
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4686
--
4687

    
4688
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4689
returns whether the map-keys of the compared values are the same
4690
(mnemonic: % is the Perl symbol for a hash map)
4691

    
4692
should be overridden for types that store both keys and values
4693

    
4694
used in a FULL JOIN to select which columns to join on
4695
';
4696

    
4697

    
4698
--
4699
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4700
--
4701

    
4702
CREATE OPERATOR -> (
4703
    PROCEDURE = map_get,
4704
    LEFTARG = regclass,
4705
    RIGHTARG = text
4706
);
4707

    
4708

    
4709
--
4710
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4711
--
4712

    
4713
CREATE OPERATOR => (
4714
    PROCEDURE = hstore,
4715
    LEFTARG = text[],
4716
    RIGHTARG = text
4717
);
4718

    
4719

    
4720
--
4721
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4722
--
4723

    
4724
COMMENT ON OPERATOR => (text[], text) IS '
4725
usage: array[''key1'', ...]::text[] => ''value''
4726
';
4727

    
4728

    
4729
--
4730
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4731
--
4732

    
4733
CREATE OPERATOR ?*>= (
4734
    PROCEDURE = is_populated_more_often_than,
4735
    LEFTARG = anyelement,
4736
    RIGHTARG = anyelement
4737
);
4738

    
4739

    
4740
--
4741
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4742
--
4743

    
4744
CREATE OPERATOR ?>= (
4745
    PROCEDURE = is_more_complete_than,
4746
    LEFTARG = anyelement,
4747
    RIGHTARG = anyelement
4748
);
4749

    
4750

    
4751
--
4752
-- Name: @; Type: OPERATOR; Schema: util; Owner: -
4753
--
4754

    
4755
CREATE OPERATOR @ (
4756
    PROCEDURE = contained_within,
4757
    LEFTARG = postgis.geography,
4758
    RIGHTARG = postgis.geography
4759
);
4760

    
4761

    
4762
--
4763
-- Name: OPERATOR @ (postgis.geography, postgis.geography); Type: COMMENT; Schema: util; Owner: -
4764
--
4765

    
4766
COMMENT ON OPERATOR @ (postgis.geography, postgis.geography) IS '
4767
can''t use && because it only compares 2D bounding boxes (which are geometry
4768
objects that do not support geocoordinate wraparound)
4769
';
4770

    
4771

    
4772
--
4773
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4774
--
4775

    
4776
CREATE OPERATOR ||% (
4777
    PROCEDURE = concat_esc,
4778
    LEFTARG = text,
4779
    RIGHTARG = text
4780
);
4781

    
4782

    
4783
--
4784
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4785
--
4786

    
4787
COMMENT ON OPERATOR ||% (text, text) IS '
4788
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4789
';
4790

    
4791

    
4792
--
4793
-- Name: ~; Type: OPERATOR; Schema: util; Owner: -
4794
--
4795

    
4796
CREATE OPERATOR ~ (
4797
    PROCEDURE = range,
4798
    LEFTARG = numeric,
4799
    RIGHTARG = numeric
4800
);
4801

    
4802

    
4803
SET search_path = pg_catalog;
4804

    
4805
--
4806
-- Name: CAST (util.range AS numrange); Type: CAST; Schema: pg_catalog; Owner: -
4807
--
4808

    
4809
CREATE CAST (util.range AS numrange) WITH FUNCTION util.numrange(util.range) AS IMPLICIT;
4810

    
4811

    
4812
SET search_path = util, pg_catalog;
4813

    
4814
--
4815
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4816
--
4817

    
4818
CREATE TABLE map (
4819
    "from" text NOT NULL,
4820
    "to" text,
4821
    filter text,
4822
    notes text
4823
);
4824

    
4825

    
4826
--
4827
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4828
--
4829

    
4830

    
4831

    
4832
--
4833
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4834
--
4835

    
4836

    
4837

    
4838
--
4839
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4840
--
4841

    
4842
ALTER TABLE ONLY map
4843
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4844

    
4845

    
4846
--
4847
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4848
--
4849

    
4850
ALTER TABLE ONLY map
4851
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4852

    
4853

    
4854
--
4855
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4856
--
4857

    
4858
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4859

    
4860

    
4861
--
4862
-- PostgreSQL database dump complete
4863
--
4864

    
(21-21/31)