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: geocoord; Type: TYPE; Schema: util; Owner: -
86
--
87

    
88
CREATE TYPE geocoord AS (
89
	latitude_deg double precision,
90
	longitude_deg double precision
91
);
92

    
93

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

    
98
CREATE TYPE range AS (
99
	lower numeric,
100
	upper numeric,
101
	bounds text
102
);
103

    
104

    
105
--
106
-- Name: TYPE range; Type: COMMENT; Schema: util; Owner: -
107
--
108

    
109
COMMENT ON TYPE range IS '
110
allows wraparound ranges (which use a modulus system such as geocoordinates)
111
';
112

    
113

    
114
--
115
-- Name: restore_views_info; Type: TYPE; Schema: util; Owner: -
116
--
117

    
118
CREATE TYPE restore_views_info AS (
119
	views db_item[]
120
);
121

    
122

    
123
--
124
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
125
--
126

    
127
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
128
    LANGUAGE sql IMMUTABLE
129
    AS $_$
130
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
131
$_$;
132

    
133

    
134
--
135
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
136
--
137

    
138
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
139
    LANGUAGE sql IMMUTABLE
140
    AS $_$
141
SELECT bool_and(value)
142
FROM
143
(VALUES
144
      ($1)
145
    , ($2)
146
    , ($3)
147
    , ($4)
148
    , ($5)
149
)
150
AS v (value)
151
$_$;
152

    
153

    
154
--
155
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
156
--
157

    
158
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
159
_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.
160
';
161

    
162

    
163
--
164
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
165
--
166

    
167
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
168
    LANGUAGE sql IMMUTABLE
169
    AS $_$
170
SELECT avg(value)
171
FROM
172
(VALUES
173
      ($1)
174
    , ($2)
175
    , ($3)
176
    , ($4)
177
    , ($5)
178
)
179
AS v (value)
180
$_$;
181

    
182

    
183
--
184
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
185
--
186

    
187
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
188
    LANGUAGE sql IMMUTABLE
189
    AS $_$
190
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)
191
FROM 
192
(
193
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
194
    UNION ALL
195
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
196
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
197
)
198
matches (g)
199
$_$;
200

    
201

    
202
--
203
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
204
--
205

    
206
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
207
    LANGUAGE sql IMMUTABLE
208
    AS $_$
209
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
210
FROM
211
(VALUES
212
      ($1)
213
    , ($2/60)
214
    , ($3/60/60)
215
)
216
AS v (value)
217
$_$;
218

    
219

    
220
--
221
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
222
--
223

    
224
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
225
    LANGUAGE sql IMMUTABLE
226
    AS $_$
227
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
228
$_$;
229

    
230

    
231
--
232
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
233
--
234

    
235
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
236
    LANGUAGE sql IMMUTABLE
237
    AS $_$
238
SELECT $1 = $2
239
$_$;
240

    
241

    
242
--
243
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
244
--
245

    
246
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
247
    LANGUAGE sql IMMUTABLE
248
    AS $_$
249
-- Fix dates after threshold date
250
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
251
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
252
$_$;
253

    
254

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

    
259
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
260
    LANGUAGE sql IMMUTABLE
261
    AS $_$
262
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
263
$_$;
264

    
265

    
266
--
267
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
268
--
269

    
270
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
271
    LANGUAGE sql IMMUTABLE
272
    AS $_$
273
SELECT util._if($1 != '', $2, $3)
274
$_$;
275

    
276

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

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

    
287

    
288
--
289
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
290
--
291

    
292
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
293
    LANGUAGE sql IMMUTABLE
294
    AS $_$
295
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
296
$_$;
297

    
298

    
299
--
300
-- Name: _km_to_m(double precision); Type: FUNCTION; Schema: util; Owner: -
301
--
302

    
303
CREATE FUNCTION _km_to_m(value double precision) RETURNS double precision
304
    LANGUAGE sql IMMUTABLE
305
    AS $_$
306
SELECT $1*1000.
307
$_$;
308

    
309

    
310
--
311
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
312
--
313

    
314
CREATE FUNCTION _label(label text, value text) RETURNS text
315
    LANGUAGE sql IMMUTABLE
316
    AS $_$
317
SELECT coalesce($1 || ': ', '') || $2
318
$_$;
319

    
320

    
321
--
322
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
323
--
324

    
325
CREATE FUNCTION _lowercase(value text) RETURNS text
326
    LANGUAGE sql IMMUTABLE
327
    AS $_$
328
SELECT lower($1)
329
$_$;
330

    
331

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

    
336
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
337
    LANGUAGE plpgsql IMMUTABLE STRICT
338
    AS $$
339
DECLARE
340
    result value%TYPE := util._map(map, value::text)::unknown;
341
BEGIN
342
    RETURN result;
343
END;
344
$$;
345

    
346

    
347
--
348
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
349
--
350

    
351
CREATE FUNCTION _map(map hstore, value text) RETURNS text
352
    LANGUAGE plpgsql IMMUTABLE STRICT
353
    AS $$
354
DECLARE
355
    match text := map -> value;
356
BEGIN
357
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
358
        match := map -> '*'; -- use default entry
359
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
360
        END IF;
361
    END IF;
362
    
363
    -- Interpret result
364
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
365
    ELSIF match = '*' THEN RETURN value;
366
    ELSE RETURN match;
367
    END IF;
368
END;
369
$$;
370

    
371

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

    
376
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
377
    LANGUAGE sql IMMUTABLE
378
    AS $_$
379
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
380
$_$;
381

    
382

    
383
--
384
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
385
--
386

    
387
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
388
    LANGUAGE sql IMMUTABLE
389
    AS $_$
390
SELECT util.join_strs(value, '; ')
391
FROM
392
(
393
    SELECT *
394
    FROM
395
    (
396
        SELECT
397
        DISTINCT ON (value)
398
        *
399
        FROM
400
        (VALUES
401
              (1, $1)
402
            , (2, $2)
403
            , (3, $3)
404
            , (4, $4)
405
            , (5, $5)
406
            , (6, $6)
407
            , (7, $7)
408
            , (8, $8)
409
            , (9, $9)
410
            , (10, $10)
411
        )
412
        AS v (sort_order, value)
413
        WHERE value IS NOT NULL
414
    )
415
    AS v
416
    ORDER BY sort_order
417
)
418
AS v
419
$_$;
420

    
421

    
422
--
423
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
424
--
425

    
426
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
427
    LANGUAGE sql IMMUTABLE
428
    AS $_$
429
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
430
$_$;
431

    
432

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

    
437
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
438
    LANGUAGE sql IMMUTABLE
439
    AS $_$
440
SELECT util.join_strs(value, ' ')
441
FROM
442
(
443
    SELECT *
444
    FROM
445
    (
446
        SELECT
447
        DISTINCT ON (value)
448
        *
449
        FROM
450
        (VALUES
451
              (1, $1)
452
            , (2, $2)
453
            , (3, $3)
454
            , (4, $4)
455
            , (5, $5)
456
            , (6, $6)
457
            , (7, $7)
458
            , (8, $8)
459
            , (9, $9)
460
            , (10, $10)
461
        )
462
        AS v (sort_order, value)
463
        WHERE value IS NOT NULL
464
    )
465
    AS v
466
    ORDER BY sort_order
467
)
468
AS v
469
$_$;
470

    
471

    
472
--
473
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
474
--
475

    
476
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
477
    LANGUAGE sql IMMUTABLE
478
    AS $_$
479
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
480
$_$;
481

    
482

    
483
--
484
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
485
--
486

    
487
CREATE FUNCTION _not(value boolean) RETURNS boolean
488
    LANGUAGE sql IMMUTABLE
489
    AS $_$
490
SELECT NOT $1
491
$_$;
492

    
493

    
494
--
495
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
496
--
497

    
498
CREATE FUNCTION _now() RETURNS timestamp with time zone
499
    LANGUAGE sql STABLE
500
    AS $$
501
SELECT now()
502
$$;
503

    
504

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

    
509
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
510
    LANGUAGE sql IMMUTABLE
511
    AS $_$
512
SELECT util."_nullIf"($1, $2, $3::util.datatype)
513
$_$;
514

    
515

    
516
--
517
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
518
--
519

    
520
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
521
    LANGUAGE plpgsql IMMUTABLE
522
    AS $$
523
DECLARE
524
    type util.datatype NOT NULL := type; -- add NOT NULL
525
BEGIN
526
    IF type = 'str' THEN RETURN nullif(value::text, "null");
527
    -- Invalid value is ignored, but invalid null value generates error
528
    ELSIF type = 'float' THEN
529
        DECLARE
530
            -- Outside the try block so that invalid null value generates error
531
            "null" double precision := "null"::double precision;
532
        BEGIN
533
            RETURN nullif(value::double precision, "null");
534
        EXCEPTION
535
            WHEN data_exception THEN RETURN value; -- ignore invalid value
536
        END;
537
    END IF;
538
END;
539
$$;
540

    
541

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

    
546
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
547
    LANGUAGE sql IMMUTABLE
548
    AS $_$
549
SELECT bool_or(value)
550
FROM
551
(VALUES
552
      ($1)
553
    , ($2)
554
    , ($3)
555
    , ($4)
556
    , ($5)
557
)
558
AS v (value)
559
$_$;
560

    
561

    
562
--
563
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
564
--
565

    
566
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
567
_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.
568
';
569

    
570

    
571
--
572
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
573
--
574

    
575
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
576
    LANGUAGE sql IMMUTABLE
577
    AS $_$
578
SELECT $2 - $1
579
$_$;
580

    
581

    
582
--
583
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
584
--
585

    
586
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
587
    LANGUAGE sql IMMUTABLE
588
    AS $_$
589
SELECT regexp_split_to_table($1, $2)
590
$_$;
591

    
592

    
593
--
594
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
595
--
596

    
597
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
598
    LANGUAGE sql STABLE
599
    AS $_$
600
SELECT util.derived_cols($1, $2)
601
UNION
602
SELECT util.eval2set($$
603
SELECT col
604
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
605
JOIN $$||$2||$$ ON "to" = col
606
WHERE "from" LIKE ':%'
607
$$, NULL::text)
608
$_$;
609

    
610

    
611
--
612
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
613
--
614

    
615
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
616
gets table_''s added columns (all the columns not in the original data)
617
';
618

    
619

    
620
--
621
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
622
--
623

    
624
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
625
    LANGUAGE sql IMMUTABLE
626
    AS $_$
627
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
628
$_$;
629

    
630

    
631
--
632
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
633
--
634

    
635
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
636
    LANGUAGE plpgsql IMMUTABLE
637
    AS $$
638
DECLARE
639
	value_cmp         state%TYPE = ARRAY[value];
640
	state             state%TYPE = COALESCE(state, value_cmp);
641
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
642
BEGIN
643
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
644
END;
645
$$;
646

    
647

    
648
--
649
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
650
--
651

    
652
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
653
    LANGUAGE sql
654
    AS $_$
655
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
656
$_$;
657

    
658

    
659
--
660
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
661
--
662

    
663
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
664
    LANGUAGE sql
665
    AS $_$
666
SELECT util.set_comment($1, concat(util.comment($1), $2))
667
$_$;
668

    
669

    
670
--
671
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
672
--
673

    
674
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
675
comment: must start and end with a newline
676
';
677

    
678

    
679
--
680
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
681
--
682

    
683
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
684
    LANGUAGE sql IMMUTABLE
685
    AS $_$
686
SELECT pg_catalog.array_fill($1, ARRAY[$2])
687
$_$;
688

    
689

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

    
694
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
695
    LANGUAGE sql IMMUTABLE
696
    AS $_$
697
SELECT util.array_length($1, 1)
698
$_$;
699

    
700

    
701
--
702
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
703
--
704

    
705
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
706
    LANGUAGE sql IMMUTABLE
707
    AS $_$
708
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
709
$_$;
710

    
711

    
712
--
713
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
714
--
715

    
716
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
717
returns 0 instead of NULL for empty arrays
718
';
719

    
720

    
721
--
722
-- Name: array_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
723
--
724

    
725
CREATE FUNCTION array_reverse("array" anyarray) RETURNS anyarray
726
    LANGUAGE sql IMMUTABLE
727
    AS $_$
728
SELECT array(SELECT elem FROM util.in_reverse($1) elem)
729
$_$;
730

    
731

    
732
--
733
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
734
--
735

    
736
CREATE FUNCTION auto_rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
737
    LANGUAGE sql
738
    AS $_$
739
SELECT CASE WHEN util.freq_always_1($1, $2)
740
THEN util.rm_freq($1, $2)
741
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
742
END
743
$_$;
744

    
745

    
746
--
747
-- Name: bounding_box(range, range); Type: FUNCTION; Schema: util; Owner: -
748
--
749

    
750
CREATE FUNCTION bounding_box(latitude_range_deg range, longitude_range_deg range) RETURNS postgis.geography
751
    LANGUAGE sql IMMUTABLE
752
    AS $_$
753
SELECT util.bounding_box__no_dateline($1, $2)::postgis.geography
754
$_$;
755

    
756

    
757
--
758
-- Name: FUNCTION bounding_box(latitude_range_deg range, longitude_range_deg range); Type: COMMENT; Schema: util; Owner: -
759
--
760

    
761
COMMENT ON FUNCTION bounding_box(latitude_range_deg range, longitude_range_deg range) IS '
762
usage:
763
SET search_path = util; -- for ~ operator
764
SELECT util.bounding_box(lower_lat ~ upper_lat, lower_long ~ upper_long);
765

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

    
771

    
772
--
773
-- Name: bounding_box__no_dateline(range, range); Type: FUNCTION; Schema: util; Owner: -
774
--
775

    
776
CREATE FUNCTION bounding_box__no_dateline(latitude_range_deg range, longitude_range_deg range) RETURNS postgis.geometry
777
    LANGUAGE sql IMMUTABLE
778
    AS $_$
779
/* don't use st_makebox2d() because it doesn't support geocoordinate wraparound
780
(it is not SRID-aware) */
781
SELECT postgis.st_makeenvelope(
782
  /*xmin=*/$2.lower, /*ymin=*/$1.lower
783
, /*xmax=*/$2.upper, /*ymax=*/$1.upper
784
, /*WGS84*/4326
785
)
786
$_$;
787

    
788

    
789
--
790
-- Name: FUNCTION bounding_box__no_dateline(latitude_range_deg range, longitude_range_deg range); Type: COMMENT; Schema: util; Owner: -
791
--
792

    
793
COMMENT ON FUNCTION bounding_box__no_dateline(latitude_range_deg range, longitude_range_deg range) IS '
794
the generated bounding box is more accurate than util.bounding_box() (latitude
795
lines will be straight), but geocoordinate wraparound is not supported
796

    
797
usage:
798
SET search_path = util; -- for ~ operator
799
SELECT util.bounding_box__no_dateline(lower_lat ~ upper_lat, lower_long ~ upper_long);
800
';
801

    
802

    
803
--
804
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
805
--
806

    
807
CREATE FUNCTION "cast"(value text, ret_type_null anyelement) RETURNS anyelement
808
    LANGUAGE plpgsql IMMUTABLE
809
    AS $$
810
/* must use LANGUAGE plpgsql because LANGUAGE sql does not assignment-cast the
811
return value, causing a type mismatch */
812
BEGIN
813
	-- will then be assignment-cast to return type via INOUT
814
	RETURN value::cstring;
815
END;
816
$$;
817

    
818

    
819
--
820
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
821
--
822

    
823
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
824
allows casting to an arbitrary type without eval()
825

    
826
usage:
827
SELECT util.cast(''value'', NULL::integer);
828

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

    
833
ret_type_null: NULL::ret_type
834
';
835

    
836

    
837
--
838
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
839
--
840

    
841
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
842
    LANGUAGE sql STABLE
843
    AS $_$
844
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
845
$_$;
846

    
847

    
848
--
849
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
850
--
851

    
852
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
853
    LANGUAGE plpgsql STRICT
854
    AS $_$
855
BEGIN
856
    -- not yet clustered (ARRAY[] compares NULLs literally)
857
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
858
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
859
    END IF;
860
END;
861
$_$;
862

    
863

    
864
--
865
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
866
--
867

    
868
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
869
idempotent
870
';
871

    
872

    
873
--
874
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
875
--
876

    
877
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
878
    LANGUAGE sql IMMUTABLE
879
    AS $_$
880
SELECT value
881
FROM unnest($1) value
882
WHERE value IS NOT NULL
883
LIMIT 1
884
$_$;
885

    
886

    
887
--
888
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
889
--
890

    
891
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
892
uses:
893
* coalescing array elements or rows together
894
* forcing evaluation of all values of a COALESCE()
895
';
896

    
897

    
898
--
899
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
900
--
901

    
902
CREATE FUNCTION col__min(col col_ref) RETURNS integer
903
    LANGUAGE sql STABLE
904
    AS $_$
905
SELECT util.eval2val($$
906
SELECT $$||quote_ident($1.name)||$$
907
FROM $$||$1.table_||$$
908
ORDER BY $$||quote_ident($1.name)||$$ ASC
909
LIMIT 1
910
$$, NULL::integer)
911
$_$;
912

    
913

    
914
--
915
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
916
--
917

    
918
CREATE FUNCTION col_comment(col col_ref) RETURNS text
919
    LANGUAGE plpgsql STABLE STRICT
920
    AS $$
921
DECLARE
922
	comment text;
923
BEGIN
924
	SELECT description
925
	FROM pg_attribute
926
	LEFT JOIN pg_description ON objoid = attrelid
927
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
928
	WHERE attrelid = col.table_ AND attname = col.name
929
	INTO STRICT comment
930
	;
931
	RETURN comment;
932
EXCEPTION
933
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
934
END;
935
$$;
936

    
937

    
938
--
939
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
940
--
941

    
942
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
943
    LANGUAGE plpgsql STABLE STRICT
944
    AS $$
945
DECLARE
946
	default_sql text;
947
BEGIN
948
	SELECT adsrc
949
	FROM pg_attribute
950
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
951
	WHERE attrelid = col.table_ AND attname = col.name
952
	INTO STRICT default_sql
953
	;
954
	RETURN default_sql;
955
EXCEPTION
956
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
957
END;
958
$$;
959

    
960

    
961
--
962
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
963
--
964

    
965
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
966
    LANGUAGE sql STABLE
967
    AS $_$
968
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
969
$_$;
970

    
971

    
972
--
973
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
974
--
975

    
976
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
977
ret_type_null: NULL::ret_type
978
';
979

    
980

    
981
--
982
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
983
--
984

    
985
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
986
    LANGUAGE plpgsql STRICT
987
    AS $$
988
BEGIN
989
    PERFORM util.col_type(col);
990
    RETURN true;
991
EXCEPTION
992
    WHEN undefined_column THEN RETURN false;
993
END;
994
$$;
995

    
996

    
997
--
998
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
999
--
1000

    
1001
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
1002
    LANGUAGE plpgsql STABLE STRICT
1003
    AS $$
1004
DECLARE
1005
    prefix text := util.name(type)||'.';
1006
BEGIN
1007
    RETURN QUERY
1008
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
1009
        FROM util.col_names(type) f (name_);
1010
END;
1011
$$;
1012

    
1013

    
1014
--
1015
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1016
--
1017

    
1018
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
1019
    LANGUAGE sql STABLE
1020
    AS $_$
1021
SELECT attname::text
1022
FROM pg_attribute
1023
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
1024
ORDER BY attnum
1025
$_$;
1026

    
1027

    
1028
--
1029
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
1030
--
1031

    
1032
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
1033
    LANGUAGE plpgsql STABLE STRICT
1034
    AS $_$
1035
BEGIN
1036
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
1037
END;
1038
$_$;
1039

    
1040

    
1041
--
1042
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
1043
--
1044

    
1045
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
1046
    LANGUAGE plpgsql STABLE STRICT
1047
    AS $$
1048
DECLARE
1049
    type regtype;
1050
BEGIN
1051
    SELECT atttypid FROM pg_attribute
1052
    WHERE attrelid = col.table_ AND attname = col.name
1053
    INTO STRICT type
1054
    ;
1055
    RETURN type;
1056
EXCEPTION
1057
    WHEN no_data_found THEN
1058
        RAISE undefined_column USING MESSAGE =
1059
            concat('undefined column: ', col.name);
1060
END;
1061
$$;
1062

    
1063

    
1064
--
1065
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
1066
--
1067

    
1068
CREATE FUNCTION comment(element oid) RETURNS text
1069
    LANGUAGE sql STABLE
1070
    AS $_$
1071
SELECT description FROM pg_description WHERE objoid = $1
1072
$_$;
1073

    
1074

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

    
1079
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
1080
    LANGUAGE sql IMMUTABLE
1081
    AS $_$
1082
SELECT util.esc_name__append($2, $1)
1083
$_$;
1084

    
1085

    
1086
--
1087
-- Name: contained_within__no_dateline(postgis.geometry, postgis.geometry); Type: FUNCTION; Schema: util; Owner: -
1088
--
1089

    
1090
CREATE FUNCTION contained_within__no_dateline("inner" postgis.geometry, "outer" postgis.geometry) RETURNS boolean
1091
    LANGUAGE sql IMMUTABLE
1092
    SET search_path TO postgis
1093
    AS $_$
1094
/* search_path: st_coveredby() needs postgis to be in the search_path */
1095
/* must be st_coveredby() rather than st_within() to avoid unexpected behavior
1096
at the shape border */
1097
SELECT postgis.st_coveredby($1, $2)
1098
$_$;
1099

    
1100

    
1101
--
1102
-- Name: FUNCTION contained_within__no_dateline("inner" postgis.geometry, "outer" postgis.geometry); Type: COMMENT; Schema: util; Owner: -
1103
--
1104

    
1105
COMMENT ON FUNCTION contained_within__no_dateline("inner" postgis.geometry, "outer" postgis.geometry) IS '
1106
**WARNING**: this will not work on shapes that cross the date line, as the
1107
geometry type does not support geocoordinate wraparound
1108
';
1109

    
1110

    
1111
--
1112
-- Name: contained_within__no_dateline(geocoord, postgis.geometry); Type: FUNCTION; Schema: util; Owner: -
1113
--
1114

    
1115
CREATE FUNCTION contained_within__no_dateline(point geocoord, region postgis.geometry) RETURNS boolean
1116
    LANGUAGE sql IMMUTABLE
1117
    AS $_$
1118
SELECT util.contained_within__no_dateline(util.geometry($1), $2)
1119
$_$;
1120

    
1121

    
1122
--
1123
-- Name: FUNCTION contained_within__no_dateline(point geocoord, region postgis.geometry); Type: COMMENT; Schema: util; Owner: -
1124
--
1125

    
1126
COMMENT ON FUNCTION contained_within__no_dateline(point geocoord, region postgis.geometry) IS '
1127
defining this in addition to contained_within_approx(geometry, geometry) enables
1128
specifying just `(lat, long)` without the ::util.geocoord type specifier
1129
';
1130

    
1131

    
1132
--
1133
-- Name: contained_within_approx(postgis.geography, postgis.geography); Type: FUNCTION; Schema: util; Owner: -
1134
--
1135

    
1136
CREATE FUNCTION contained_within_approx("inner" postgis.geography, "outer" postgis.geography) RETURNS boolean
1137
    LANGUAGE sql IMMUTABLE
1138
    SET search_path TO postgis
1139
    AS $_$
1140
/* search_path: st_coveredby() needs postgis to be in the search_path */
1141
SELECT postgis.st_coveredby($1, $2)
1142
$_$;
1143

    
1144

    
1145
--
1146
-- Name: FUNCTION contained_within_approx("inner" postgis.geography, "outer" postgis.geography); Type: COMMENT; Schema: util; Owner: -
1147
--
1148

    
1149
COMMENT ON FUNCTION contained_within_approx("inner" postgis.geography, "outer" postgis.geography) IS '
1150
**WARNING**: the geography type stores all edges as arcs of great circles,
1151
resulting in the latitude lines of bounding boxes bulging outward from the true
1152
bounding box. this will create false positives above and below the bounding box.
1153
';
1154

    
1155

    
1156
--
1157
-- Name: contained_within_approx(geocoord, postgis.geography); Type: FUNCTION; Schema: util; Owner: -
1158
--
1159

    
1160
CREATE FUNCTION contained_within_approx(point geocoord, region postgis.geography) RETURNS boolean
1161
    LANGUAGE sql IMMUTABLE
1162
    AS $_$
1163
SELECT util.contained_within_approx(util.geometry($1), $2)
1164
$_$;
1165

    
1166

    
1167
--
1168
-- Name: FUNCTION contained_within_approx(point geocoord, region postgis.geography); Type: COMMENT; Schema: util; Owner: -
1169
--
1170

    
1171
COMMENT ON FUNCTION contained_within_approx(point geocoord, region postgis.geography) IS '
1172
defining this in addition to contained_within_approx(geography, geography)
1173
enables specifying just `(lat, long)` without the ::util.geocoord type specifier
1174
';
1175

    
1176

    
1177
--
1178
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
1179
--
1180

    
1181
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
1182
    LANGUAGE sql IMMUTABLE
1183
    AS $_$
1184
SELECT position($1 in $2) > 0 /*1-based offset*/
1185
$_$;
1186

    
1187

    
1188
--
1189
-- Name: copy(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1190
--
1191

    
1192
CREATE FUNCTION copy(from_ regclass, to_ text) RETURNS void
1193
    LANGUAGE sql
1194
    AS $_$
1195
SELECT util.copy_struct($1, $2);
1196
SELECT util.copy_data($1, $2);
1197
$_$;
1198

    
1199

    
1200
--
1201
-- Name: copy_data(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1202
--
1203

    
1204
CREATE FUNCTION copy_data(from_ regclass, to_ regclass) RETURNS void
1205
    LANGUAGE sql
1206
    AS $_$
1207
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT * FROM $$||$1)
1208
$_$;
1209

    
1210

    
1211
--
1212
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1213
--
1214

    
1215
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1216
    LANGUAGE sql
1217
    AS $_$
1218
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1219
$_$;
1220

    
1221

    
1222
--
1223
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1224
--
1225

    
1226
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1227
    LANGUAGE sql
1228
    AS $_$
1229
SELECT util.materialize_view($2, $1)
1230
$_$;
1231

    
1232

    
1233
--
1234
-- Name: create_if_not_exists(text, text); Type: FUNCTION; Schema: util; Owner: -
1235
--
1236

    
1237
CREATE FUNCTION create_if_not_exists(sql text, relation text DEFAULT NULL::text) RETURNS void
1238
    LANGUAGE plpgsql
1239
    AS $$
1240
BEGIN
1241
	/* always generate standard exception if exists, even if table definition
1242
	would be invalid (which generates a variety of exceptions) */
1243
	IF util.relation_exists(relation) THEN
1244
		PERFORM util.raise('NOTICE', relation||' already exists, skipping');
1245
		RAISE duplicate_table;
1246
	END IF;
1247
	PERFORM util.eval(sql);
1248
EXCEPTION
1249
WHEN   duplicate_table
1250
	OR duplicate_object -- eg. constraint
1251
	OR duplicate_column
1252
	OR duplicate_function
1253
THEN NULL;
1254
WHEN invalid_table_definition THEN
1255
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1256
	ELSE RAISE;
1257
	END IF;
1258
END;
1259
$$;
1260

    
1261

    
1262
--
1263
-- Name: FUNCTION create_if_not_exists(sql text, relation text); Type: COMMENT; Schema: util; Owner: -
1264
--
1265

    
1266
COMMENT ON FUNCTION create_if_not_exists(sql text, relation text) IS '
1267
idempotent
1268
';
1269

    
1270

    
1271
--
1272
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1273
--
1274

    
1275
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1276
    LANGUAGE sql STABLE
1277
    AS $$
1278
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1279
$$;
1280

    
1281

    
1282
--
1283
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1284
--
1285

    
1286
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1287
    LANGUAGE sql IMMUTABLE
1288
    AS $_$
1289
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1290
$_$;
1291

    
1292

    
1293
--
1294
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1295
--
1296

    
1297
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1298
    LANGUAGE sql IMMUTABLE
1299
    AS $_$
1300
SELECT util.debug_print_value('returns: ', $1, $2);
1301
SELECT $1;
1302
$_$;
1303

    
1304

    
1305
--
1306
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1307
--
1308

    
1309
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1310
    LANGUAGE sql IMMUTABLE
1311
    AS $_$
1312
/* newline before so the query starts at the beginning of the line.
1313
newline after to visually separate queries from one another. */
1314
SELECT util.raise('NOTICE', $$
1315
$$||util.runnable_sql($1)||$$
1316
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1317
$_$;
1318

    
1319

    
1320
--
1321
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1322
--
1323

    
1324
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1325
    LANGUAGE sql IMMUTABLE
1326
    AS $_$
1327
SELECT util.raise('NOTICE', concat($1,
1328
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1329
$$)
1330
$_$;
1331

    
1332

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

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

    
1346

    
1347
--
1348
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1349
--
1350

    
1351
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1352
    LANGUAGE sql STABLE
1353
    AS $_$
1354
SELECT util.eval2set($$
1355
SELECT col
1356
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1357
LEFT JOIN $$||$2||$$ ON "to" = col
1358
WHERE "from" IS NULL
1359
$$, NULL::text)
1360
$_$;
1361

    
1362

    
1363
--
1364
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1365
--
1366

    
1367
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1368
gets table_''s derived columns (all the columns not in the names table)
1369
';
1370

    
1371

    
1372
--
1373
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1374
--
1375

    
1376
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1377
    LANGUAGE sql
1378
    AS $_$
1379
-- create a diff when the # of copies of a row differs between the tables
1380
SELECT util.to_freq($1);
1381
SELECT util.to_freq($2);
1382
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1383

    
1384
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1385
$_$;
1386

    
1387

    
1388
--
1389
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1390
--
1391

    
1392
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1393
usage:
1394
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1395

    
1396
col_type_null (*required*): NULL::shared_base_type
1397
';
1398

    
1399

    
1400
--
1401
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1402
--
1403

    
1404
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
1405
    LANGUAGE plpgsql
1406
    SET search_path TO pg_temp
1407
    AS $_$
1408
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1409
changes of search_path (schema elements are bound at inline time rather than
1410
runtime) */
1411
/* function option search_path is needed to limit the effects of
1412
`SET LOCAL search_path` to the current function */
1413
BEGIN
1414
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1415
	
1416
	PERFORM util.mk_keys_func(pg_typeof($3));
1417
	RETURN QUERY
1418
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1419
$$/* need to explicitly cast each side to the return type because this does not
1420
happen automatically even when an implicit cast is available */
1421
  left_::$$||util.typeof($3)||$$
1422
, right_::$$||util.typeof($3)
1423
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1424
the *same* base type, *even though* this is optional when using a custom %== */
1425
, util._if($4, $$true/*= CROSS JOIN*/$$,
1426
$$ left_::$$||util.typeof($3)||$$
1427
%== right_::$$||util.typeof($3)||$$
1428
	-- refer to EXPLAIN output for expansion of %==$$
1429
)
1430
,     $$         left_::$$||util.typeof($3)||$$
1431
IS DISTINCT FROM right_::$$||util.typeof($3)
1432
), $3)
1433
	;
1434
END;
1435
$_$;
1436

    
1437

    
1438
--
1439
-- 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: -
1440
--
1441

    
1442
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1443
col_type_null (*required*): NULL::col_type
1444
single_row: whether the tables consist of a single row, which should be
1445
	displayed side-by-side
1446

    
1447
to match up rows using a subset of the columns, create a custom keys() function
1448
which returns this subset as a record:
1449
-- note that OUT parameters for the returned fields are *not* needed
1450
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1451
  RETURNS record AS
1452
$BODY$
1453
SELECT ($1.key_field_0, $1.key_field_1)
1454
$BODY$
1455
  LANGUAGE sql IMMUTABLE
1456
  COST 100;
1457

    
1458

    
1459
to run EXPLAIN on the FULL JOIN query:
1460
# run this function
1461
# look for a NOTICE containing the expanded query that it ran
1462
# run EXPLAIN on this expanded query
1463
';
1464

    
1465

    
1466
--
1467
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1468
--
1469

    
1470
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
1471
    LANGUAGE sql
1472
    AS $_$
1473
SELECT * FROM util.diff($1::text, $2::text, $3,
1474
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1475
$_$;
1476

    
1477

    
1478
--
1479
-- 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: -
1480
--
1481

    
1482
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1483
helper function used by diff(regclass, regclass)
1484

    
1485
usage:
1486
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1487

    
1488
col_type_null (*required*): NULL::shared_base_type
1489
';
1490

    
1491

    
1492
--
1493
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1494
--
1495

    
1496
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1497
    LANGUAGE sql
1498
    AS $_$
1499
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1500
$_$;
1501

    
1502

    
1503
--
1504
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1505
--
1506

    
1507
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1508
idempotent
1509
';
1510

    
1511

    
1512
--
1513
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1514
--
1515

    
1516
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1517
    LANGUAGE sql
1518
    AS $_$
1519
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1520
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1521
$_$;
1522

    
1523

    
1524
--
1525
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1526
--
1527

    
1528
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1529
idempotent
1530
';
1531

    
1532

    
1533
--
1534
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1535
--
1536

    
1537
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1538
    LANGUAGE sql
1539
    AS $_$
1540
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1541
SELECT NULL::void; -- don't fold away functions called in previous query
1542
$_$;
1543

    
1544

    
1545
--
1546
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1547
--
1548

    
1549
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1550
idempotent
1551
';
1552

    
1553

    
1554
--
1555
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1556
--
1557

    
1558
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1559
    LANGUAGE sql
1560
    AS $_$
1561
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1562
included in the debug SQL */
1563
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1564
$_$;
1565

    
1566

    
1567
--
1568
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1569
--
1570

    
1571
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1572
    LANGUAGE sql
1573
    AS $_$
1574
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1575
||util._if($3, $$ CASCADE$$, ''::text))
1576
$_$;
1577

    
1578

    
1579
--
1580
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1581
--
1582

    
1583
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1584
idempotent
1585
';
1586

    
1587

    
1588
--
1589
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1590
--
1591

    
1592
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1593
    LANGUAGE sql
1594
    AS $_$
1595
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1596
$_$;
1597

    
1598

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

    
1603
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1604
    LANGUAGE sql
1605
    AS $_$
1606
SELECT util.debug_print_func_call(util.quote_func_call(
1607
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1608
util.quote_typed($3)))
1609
;
1610
SELECT util.drop_relation(relation, $3)
1611
FROM util.show_relations_like($1, $2) relation
1612
;
1613
SELECT NULL::void; -- don't fold away functions called in previous query
1614
$_$;
1615

    
1616

    
1617
--
1618
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1619
--
1620

    
1621
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1622
    LANGUAGE sql
1623
    AS $_$
1624
SELECT util.drop_relation('TABLE', $1, $2)
1625
$_$;
1626

    
1627

    
1628
--
1629
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1630
--
1631

    
1632
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1633
idempotent
1634
';
1635

    
1636

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

    
1641
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1642
    LANGUAGE sql
1643
    AS $_$
1644
SELECT util.drop_relation('VIEW', $1, $2)
1645
$_$;
1646

    
1647

    
1648
--
1649
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1650
--
1651

    
1652
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1653
idempotent
1654
';
1655

    
1656

    
1657
--
1658
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1659
--
1660

    
1661
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1662
    LANGUAGE sql IMMUTABLE
1663
    AS $_$
1664
SELECT util.array_fill($1, 0)
1665
$_$;
1666

    
1667

    
1668
--
1669
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1670
--
1671

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

    
1676

    
1677
--
1678
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1679
--
1680

    
1681
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1682
    LANGUAGE sql IMMUTABLE
1683
    AS $_$
1684
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1685
$_$;
1686

    
1687

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

    
1692
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1693
    LANGUAGE sql IMMUTABLE
1694
    AS $_$
1695
SELECT regexp_replace($2, '("?)$', $1||'\1')
1696
$_$;
1697

    
1698

    
1699
--
1700
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1701
--
1702

    
1703
CREATE FUNCTION eval(queries text[]) RETURNS void
1704
    LANGUAGE sql
1705
    AS $_$
1706
SELECT util.eval(query) FROM unnest($1) query;
1707
SELECT NULL::void; -- don't fold away functions called in previous query
1708
$_$;
1709

    
1710

    
1711
--
1712
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1713
--
1714

    
1715
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1716
    LANGUAGE plpgsql
1717
    AS $$
1718
BEGIN
1719
	sql = util.view_def_to_orig(sql); -- restore user's intent
1720
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1721
	EXECUTE sql;
1722
END;
1723
$$;
1724

    
1725

    
1726
--
1727
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1728
--
1729

    
1730
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1731
    LANGUAGE plpgsql
1732
    AS $$
1733
BEGIN
1734
	PERFORM util.debug_print_sql(sql);
1735
	RETURN QUERY EXECUTE sql;
1736
END;
1737
$$;
1738

    
1739

    
1740
--
1741
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1742
--
1743

    
1744
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1745
col_type_null (*required*): NULL::col_type
1746
';
1747

    
1748

    
1749
--
1750
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1751
--
1752

    
1753
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1754
    LANGUAGE plpgsql
1755
    AS $$
1756
BEGIN
1757
	PERFORM util.debug_print_sql(sql);
1758
	RETURN QUERY EXECUTE sql;
1759
END;
1760
$$;
1761

    
1762

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

    
1767
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1768
    LANGUAGE plpgsql
1769
    AS $$
1770
BEGIN
1771
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1772
	RETURN QUERY EXECUTE sql;
1773
END;
1774
$$;
1775

    
1776

    
1777
--
1778
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1779
--
1780

    
1781
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1782
    LANGUAGE plpgsql STABLE
1783
    AS $$
1784
DECLARE
1785
	ret_val ret_type_null%TYPE;
1786
BEGIN
1787
	PERFORM util.debug_print_sql(sql);
1788
	EXECUTE sql INTO STRICT ret_val;
1789
	RETURN ret_val;
1790
END;
1791
$$;
1792

    
1793

    
1794
--
1795
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1796
--
1797

    
1798
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1799
ret_type_null: NULL::ret_type
1800
';
1801

    
1802

    
1803
--
1804
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1805
--
1806

    
1807
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1808
    LANGUAGE sql
1809
    AS $_$
1810
SELECT util.eval2val($$SELECT $$||$1, $2)
1811
$_$;
1812

    
1813

    
1814
--
1815
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1816
--
1817

    
1818
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1819
ret_type_null: NULL::ret_type
1820
';
1821

    
1822

    
1823
--
1824
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1825
--
1826

    
1827
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1828
    LANGUAGE sql
1829
    AS $_$
1830
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1831
$_$;
1832

    
1833

    
1834
--
1835
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1836
--
1837

    
1838
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1839
sql: can be NULL, which will be passed through
1840
ret_type_null: NULL::ret_type
1841
';
1842

    
1843

    
1844
--
1845
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1846
--
1847

    
1848
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1849
    LANGUAGE sql STABLE
1850
    AS $_$
1851
SELECT col_name
1852
FROM unnest($2) s (col_name)
1853
WHERE util.col_exists(($1, col_name))
1854
$_$;
1855

    
1856

    
1857
--
1858
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1859
--
1860

    
1861
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1862
    LANGUAGE sql
1863
    SET client_min_messages TO 'error'
1864
    AS $_$
1865
/* `client_min_messages = ERROR`: EXPLAIN apparently runs IMMUTABLE functions in
1866
the query, so this prevents displaying any log messages printed by them */
1867
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1868
$_$;
1869

    
1870

    
1871
--
1872
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1873
--
1874

    
1875
CREATE FUNCTION explain2notice(sql text) RETURNS void
1876
    LANGUAGE sql
1877
    AS $_$
1878
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1879
$_$;
1880

    
1881

    
1882
--
1883
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1884
--
1885

    
1886
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1887
    LANGUAGE sql
1888
    AS $_$
1889
-- newline before and after to visually separate it from other debug info
1890
SELECT COALESCE($$
1891
EXPLAIN:
1892
$$||util.fold_explain_msg(util.explain2str($1))||$$
1893
$$, '')
1894
$_$;
1895

    
1896

    
1897
--
1898
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1899
--
1900

    
1901
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1902
    LANGUAGE plpgsql
1903
    AS $$
1904
BEGIN
1905
	RETURN util.explain2notice_msg(sql);
1906
EXCEPTION
1907
WHEN   syntax_error
1908
	OR invalid_cursor_definition -- "cannot open multi-query plan as cursor"
1909
	THEN RETURN NULL; -- non-explainable query
1910
	/* don't use util.is_explainable() because the list provided by Postgres
1911
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1912
	excludes some query types that are in fact EXPLAIN-able */
1913
END;
1914
$$;
1915

    
1916

    
1917
--
1918
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1919
--
1920

    
1921
CREATE FUNCTION explain2str(sql text) RETURNS text
1922
    LANGUAGE sql
1923
    AS $_$
1924
SELECT util.join_strs(explain, $$
1925
$$) FROM util.explain($1)
1926
$_$;
1927

    
1928

    
1929
SET default_tablespace = '';
1930

    
1931
SET default_with_oids = false;
1932

    
1933
--
1934
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1935
--
1936

    
1937
CREATE TABLE explain (
1938
    line text NOT NULL
1939
);
1940

    
1941

    
1942
--
1943
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1944
--
1945

    
1946
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1947
    LANGUAGE sql
1948
    AS $_$
1949
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1950
$$||quote_nullable($1)||$$
1951
)$$)
1952
$_$;
1953

    
1954

    
1955
--
1956
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1957
--
1958

    
1959
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1960
usage:
1961
PERFORM util.explain2table($$
1962
query
1963
$$);
1964
';
1965

    
1966

    
1967
--
1968
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1969
--
1970

    
1971
CREATE FUNCTION first_word(str text) RETURNS text
1972
    LANGUAGE sql IMMUTABLE
1973
    AS $_$
1974
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1975
$_$;
1976

    
1977

    
1978
--
1979
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1980
--
1981

    
1982
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1983
    LANGUAGE sql IMMUTABLE
1984
    AS $_$
1985
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1986
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1987
) END
1988
$_$;
1989

    
1990

    
1991
--
1992
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1993
--
1994

    
1995
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1996
ensures that an array will always have proper non-NULL dimensions
1997
';
1998

    
1999

    
2000
--
2001
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
2002
--
2003

    
2004
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
2005
    LANGUAGE sql IMMUTABLE
2006
    AS $_$
2007
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
2008
$_$;
2009

    
2010

    
2011
--
2012
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
2013
--
2014

    
2015
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
2016
    LANGUAGE plpgsql STRICT
2017
    AS $_$
2018
DECLARE
2019
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
2020
$$||query;
2021
BEGIN
2022
	EXECUTE mk_view;
2023
EXCEPTION
2024
WHEN invalid_table_definition THEN
2025
	IF SQLERRM = 'cannot drop columns from view'
2026
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
2027
	THEN
2028
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
2029
		EXECUTE mk_view;
2030
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
2031
	END IF;
2032
END;
2033
$_$;
2034

    
2035

    
2036
--
2037
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
2038
--
2039

    
2040
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
2041
idempotent
2042
';
2043

    
2044

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

    
2049
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
2050
    LANGUAGE sql STABLE
2051
    AS $_$
2052
SELECT util.eval2val(
2053
$$SELECT NOT EXISTS( -- there is no row that is != 1
2054
	SELECT NULL
2055
	FROM $$||$1||$$
2056
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
2057
	LIMIT 1
2058
)
2059
$$, NULL::boolean)
2060
$_$;
2061

    
2062

    
2063
--
2064
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
2065
--
2066

    
2067
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
2068
    LANGUAGE sql STABLE
2069
    AS $_$
2070
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
2071
$_$;
2072

    
2073

    
2074
--
2075
-- Name: geometry(geocoord); Type: FUNCTION; Schema: util; Owner: -
2076
--
2077

    
2078
CREATE FUNCTION geometry(geocoord geocoord) RETURNS postgis.geometry
2079
    LANGUAGE sql IMMUTABLE
2080
    SET client_min_messages TO 'warning'
2081
    AS $_$
2082
SELECT postgis.st_setsrid(postgis.st_point(
2083
/*x_lon=*/$1.longitude_deg, /*y_lat=*/$1.latitude_deg),
2084
/*WGS84*/4326)
2085
$_$;
2086

    
2087

    
2088
--
2089
-- Name: FUNCTION geometry(geocoord geocoord); Type: COMMENT; Schema: util; Owner: -
2090
--
2091

    
2092
COMMENT ON FUNCTION geometry(geocoord geocoord) IS '
2093
*note*: it is not possible to create a cast for this, as a bug in pg_dump
2094
prevents the cast from being exported, even when no export filters are applied
2095
';
2096

    
2097

    
2098
--
2099
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
2100
--
2101

    
2102
CREATE FUNCTION grants_users() RETURNS SETOF text
2103
    LANGUAGE sql IMMUTABLE
2104
    AS $$
2105
VALUES ('bien_read'), ('public_')
2106
$$;
2107

    
2108

    
2109
--
2110
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
2111
--
2112

    
2113
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
2114
    LANGUAGE sql IMMUTABLE
2115
    AS $_$
2116
SELECT substring($2 for length($1)) = $1
2117
$_$;
2118

    
2119

    
2120
--
2121
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
2122
--
2123

    
2124
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
2125
    LANGUAGE sql STABLE
2126
    AS $_$
2127
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
2128
$_$;
2129

    
2130

    
2131
--
2132
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
2133
--
2134

    
2135
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
2136
    LANGUAGE sql IMMUTABLE
2137
    AS $_$
2138
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
2139
$_$;
2140

    
2141

    
2142
--
2143
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
2144
--
2145

    
2146
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
2147
avoids repeating the same value for each key
2148
';
2149

    
2150

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

    
2155
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
2156
    LANGUAGE sql IMMUTABLE
2157
    AS $_$
2158
SELECT COALESCE($1, $2)
2159
$_$;
2160

    
2161

    
2162
--
2163
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
2164
--
2165

    
2166
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
2167
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
2168
';
2169

    
2170

    
2171
--
2172
-- Name: in_new_world(geocoord); Type: FUNCTION; Schema: util; Owner: -
2173
--
2174

    
2175
CREATE FUNCTION in_new_world(point geocoord) RETURNS boolean
2176
    LANGUAGE sql IMMUTABLE
2177
    AS $_$
2178
/* use function rather than operator+search_path to allow inlining, which
2179
enables util.new_world() to only be evaluated once */
2180
SELECT util.contained_within_approx($1, util.new_world())
2181
$_$;
2182

    
2183

    
2184
--
2185
-- Name: FUNCTION in_new_world(point geocoord); Type: COMMENT; Schema: util; Owner: -
2186
--
2187

    
2188
COMMENT ON FUNCTION in_new_world(point geocoord) IS '
2189
**WARNING**: this includes false positives above and below the New World
2190
bounding box, as described in util.bounding_box()
2191
';
2192

    
2193

    
2194
--
2195
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
2196
--
2197

    
2198
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
2199
    LANGUAGE sql IMMUTABLE
2200
    AS $_$
2201
SELECT elem FROM unnest($1) elem ORDER BY row_number() OVER () DESC
2202
$_$;
2203

    
2204

    
2205
--
2206
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2207
--
2208

    
2209
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
2210
    LANGUAGE sql
2211
    AS $_$
2212
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
2213
$_$;
2214

    
2215

    
2216
--
2217
-- Name: is_castable(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2218
--
2219

    
2220
CREATE FUNCTION is_castable(value text, ret_type_null anyelement) RETURNS boolean
2221
    LANGUAGE plpgsql IMMUTABLE
2222
    AS $$
2223
BEGIN
2224
	PERFORM util.cast(value, ret_type_null);
2225
	-- must happen *after* cast check, because NULL is not valid for some types
2226
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
2227
	RETURN true;
2228
EXCEPTION
2229
WHEN   data_exception
2230
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
2231
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
2232
	THEN
2233
	RETURN false;
2234
END;
2235
$$;
2236

    
2237

    
2238
--
2239
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
2240
--
2241

    
2242
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
2243
passes NULL through. however, if NULL is not valid for the type, false will be
2244
returned instead.
2245

    
2246
ret_type_null: NULL::ret_type
2247
';
2248

    
2249

    
2250
--
2251
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
2252
--
2253

    
2254
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
2255
    LANGUAGE sql STABLE
2256
    AS $_$
2257
SELECT COALESCE(util.col_comment($1) LIKE '
2258
constant
2259
%', false)
2260
$_$;
2261

    
2262

    
2263
--
2264
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2265
--
2266

    
2267
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
2268
    LANGUAGE sql IMMUTABLE
2269
    AS $_$
2270
SELECT util.array_length($1) = 0
2271
$_$;
2272

    
2273

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

    
2278
CREATE FUNCTION is_explain(sql text) RETURNS boolean
2279
    LANGUAGE sql IMMUTABLE
2280
    AS $_$
2281
SELECT upper(util.first_word($1)) = 'EXPLAIN'
2282
$_$;
2283

    
2284

    
2285
--
2286
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
2287
--
2288

    
2289
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
2290
    LANGUAGE sql IMMUTABLE
2291
    AS $_$
2292
SELECT upper(util.first_word($1)) = ANY(
2293
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
2294
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
2295
)
2296
$_$;
2297

    
2298

    
2299
--
2300
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2301
--
2302

    
2303
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
2304
    LANGUAGE sql IMMUTABLE
2305
    AS $_$
2306
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2307
$_$;
2308

    
2309

    
2310
--
2311
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2312
--
2313

    
2314
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2315
    LANGUAGE sql IMMUTABLE
2316
    AS $_$
2317
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2318
$_$;
2319

    
2320

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

    
2325
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2326
    LANGUAGE sql IMMUTABLE
2327
    AS $_$
2328
SELECT upper(util.first_word($1)) = 'SET'
2329
$_$;
2330

    
2331

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

    
2336
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2337
    LANGUAGE sql STABLE
2338
    AS $_$
2339
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2340
$_$;
2341

    
2342

    
2343
--
2344
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2345
--
2346

    
2347
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2348
    LANGUAGE sql STABLE
2349
    AS $_$
2350
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2351
$_$;
2352

    
2353

    
2354
--
2355
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2356
--
2357

    
2358
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2359
    LANGUAGE sql IMMUTABLE STRICT
2360
    AS $_$
2361
SELECT $1 || $3 || $2
2362
$_$;
2363

    
2364

    
2365
--
2366
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2367
--
2368

    
2369
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2370
must be declared STRICT to use the special handling of STRICT aggregating functions
2371
';
2372

    
2373

    
2374
--
2375
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2376
--
2377

    
2378
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2379
    LANGUAGE sql IMMUTABLE
2380
    AS $_$
2381
SELECT $1 -- compare on the entire value
2382
$_$;
2383

    
2384

    
2385
--
2386
-- Name: keys_eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2387
--
2388

    
2389
CREATE FUNCTION keys_eq(left_ anyelement, right_ anyelement) RETURNS boolean
2390
    LANGUAGE sql STABLE
2391
    AS $_$
2392
SELECT keys($1) = keys($2)
2393
$_$;
2394

    
2395

    
2396
--
2397
-- Name: FUNCTION keys_eq(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
2398
--
2399

    
2400
COMMENT ON FUNCTION keys_eq(left_ anyelement, right_ anyelement) IS '
2401
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**)
2402
';
2403

    
2404

    
2405
--
2406
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2407
--
2408

    
2409
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2410
    LANGUAGE sql IMMUTABLE
2411
    AS $_$
2412
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2413
$_$;
2414

    
2415

    
2416
--
2417
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2418
--
2419

    
2420
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2421
    LANGUAGE plpgsql
2422
    AS $$
2423
DECLARE
2424
	errors_ct integer = 0;
2425
	loop_var loop_type_null%TYPE;
2426
BEGIN
2427
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2428
	LOOP
2429
		BEGIN
2430
			EXECUTE loop_body_sql USING loop_var;
2431
		EXCEPTION
2432
		WHEN OTHERS THEN
2433
			errors_ct = errors_ct+1;
2434
			PERFORM util.raise_error_warning(SQLERRM);
2435
		END;
2436
	END LOOP;
2437
	IF errors_ct > 0 THEN
2438
		-- can't raise exception because this would roll back the transaction
2439
		PERFORM util.raise_error_warning('there were '||errors_ct
2440
			||' errors: see the WARNINGs for details');
2441
	END IF;
2442
END;
2443
$$;
2444

    
2445

    
2446
--
2447
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2448
--
2449

    
2450
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2451
    LANGUAGE sql IMMUTABLE
2452
    AS $_$
2453
SELECT ltrim($1, $$
2454
$$)
2455
$_$;
2456

    
2457

    
2458
--
2459
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2460
--
2461

    
2462
CREATE FUNCTION map_filter_insert() RETURNS trigger
2463
    LANGUAGE plpgsql
2464
    AS $$
2465
BEGIN
2466
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2467
	RETURN new;
2468
END;
2469
$$;
2470

    
2471

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

    
2476
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2477
    LANGUAGE plpgsql STABLE STRICT
2478
    AS $_$
2479
DECLARE
2480
    value text;
2481
BEGIN
2482
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2483
        INTO value USING key;
2484
    RETURN value;
2485
END;
2486
$_$;
2487

    
2488

    
2489
--
2490
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2491
--
2492

    
2493
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2494
    LANGUAGE sql IMMUTABLE
2495
    AS $_$
2496
SELECT util._map(util.nulls_map($1), $2)
2497
$_$;
2498

    
2499

    
2500
--
2501
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2502
--
2503

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

    
2507
[1] inlining of function calls, which is different from constant folding
2508
[2] _map()''s profiling query
2509
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2510
and map_nulls()''s profiling query
2511
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2512
both take ~920 ms.
2513
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.
2514
';
2515

    
2516

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

    
2521
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2522
    LANGUAGE plpgsql STABLE STRICT
2523
    AS $_$
2524
BEGIN
2525
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2526
END;
2527
$_$;
2528

    
2529

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

    
2534
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2535
    LANGUAGE sql
2536
    AS $_$
2537
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2538
$$||util.ltrim_nl($2));
2539
-- make sure the created table has the correct estimated row count
2540
SELECT util.analyze_($1);
2541

    
2542
SELECT util.append_comment($1, '
2543
contents generated from:
2544
'||util.ltrim_nl(util.runnable_sql($2))||';
2545
');
2546
$_$;
2547

    
2548

    
2549
--
2550
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2551
--
2552

    
2553
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2554
idempotent
2555
';
2556

    
2557

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

    
2562
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2563
    LANGUAGE sql
2564
    AS $_$
2565
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2566
$_$;
2567

    
2568

    
2569
--
2570
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2571
--
2572

    
2573
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2574
idempotent
2575
';
2576

    
2577

    
2578
--
2579
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2580
--
2581

    
2582
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2583
    LANGUAGE sql
2584
    AS $_$
2585
SELECT util.create_if_not_exists($$
2586
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2587
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2588
||quote_literal($2)||$$;
2589
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2590
constant
2591
';
2592
$$)
2593
$_$;
2594

    
2595

    
2596
--
2597
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2598
--
2599

    
2600
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2601
idempotent
2602
';
2603

    
2604

    
2605
--
2606
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2607
--
2608

    
2609
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2610
    LANGUAGE plpgsql STRICT
2611
    AS $_$
2612
DECLARE
2613
    type regtype = util.typeof(expr, col.table_::text::regtype);
2614
    col_name_sql text = quote_ident(col.name);
2615
BEGIN
2616
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2617
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2618
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2619
$$||expr||$$;
2620
$$);
2621
END;
2622
$_$;
2623

    
2624

    
2625
--
2626
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2627
--
2628

    
2629
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2630
idempotent
2631
';
2632

    
2633

    
2634
--
2635
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2636
--
2637

    
2638
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
2639
    LANGUAGE sql IMMUTABLE
2640
    AS $_$
2641
SELECT
2642
$$SELECT
2643
$$||$3||$$
2644
FROM      $$||$1||$$ left_
2645
FULL JOIN $$||$2||$$ right_
2646
ON $$||$4||$$
2647
WHERE $$||$5||$$
2648
ORDER BY left_, right_
2649
$$
2650
$_$;
2651

    
2652

    
2653
--
2654
-- Name: mk_drop_from_create(text); Type: FUNCTION; Schema: util; Owner: -
2655
--
2656

    
2657
CREATE FUNCTION mk_drop_from_create(create_cmd text) RETURNS text
2658
    LANGUAGE sql IMMUTABLE
2659
    AS $_$
2660
SELECT $$DROP $$||(util.regexp_match($1,
2661
-- match first CREATE, *if* no DROP came before it
2662
'(?m)\A(?:^(?!DROP\y).*\n)*?^CREATE(?: OR REPLACE)? ((?:)??[[:upper:]]+ .*?)(?: AS(?: (?:SELECT\y.*)?)?)?$'
2663
	/* (?:)?? makes the surrounding () group non-greedy, so that (?: AS ?)?
2664
	works properly (due to nonstandard Postgres regexp behavior:
2665
	http://www.postgresql.org/docs/9.3/static/functions-matching.html#POSIX-MATCHING-RULES) */
2666
))[1]||$$;$$
2667
$_$;
2668

    
2669

    
2670
--
2671
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2672
--
2673

    
2674
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2675
    LANGUAGE sql
2676
    AS $_$
2677
-- keys()
2678
SELECT util.mk_keys_func($1, ARRAY(
2679
SELECT col FROM util.typed_cols($1) col
2680
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2681
));
2682

    
2683
-- values_()
2684
SELECT util.mk_keys_func($1, COALESCE(
2685
	NULLIF(ARRAY(
2686
	SELECT col FROM util.typed_cols($1) col
2687
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2688
	), ARRAY[]::util.col_cast[])
2689
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2690
, 'values_');
2691
$_$;
2692

    
2693

    
2694
--
2695
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2696
--
2697

    
2698
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2699
    LANGUAGE sql
2700
    AS $_$
2701
SELECT util.create_if_not_exists($$
2702
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2703
($$||util.mk_typed_cols_list($2)||$$);
2704
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2705
autogenerated
2706
';
2707
$$);
2708

    
2709
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2710
$_$;
2711

    
2712

    
2713
--
2714
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2715
--
2716

    
2717
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2718
    LANGUAGE sql
2719
    AS $_$
2720
SELECT util.create_if_not_exists($$
2721
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2722
||util.qual_name($1)||$$)
2723
  RETURNS $$||util.qual_name($2)||$$ AS
2724
$BODY1$
2725
SELECT ROW($$||
2726
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2727
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2728
$BODY1$
2729
  LANGUAGE sql IMMUTABLE
2730
  COST 100;
2731
$$);
2732
$_$;
2733

    
2734

    
2735
--
2736
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2737
--
2738

    
2739
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2740
    LANGUAGE sql
2741
    AS $_$
2742
SELECT util.create_if_not_exists($$
2743
CREATE TABLE $$||$1||$$
2744
(
2745
    LIKE util.map INCLUDING ALL
2746
);
2747

    
2748
CREATE TRIGGER map_filter_insert
2749
  BEFORE INSERT
2750
  ON $$||$1||$$
2751
  FOR EACH ROW
2752
  EXECUTE PROCEDURE util.map_filter_insert();
2753
$$)
2754
$_$;
2755

    
2756

    
2757
--
2758
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2759
--
2760

    
2761
CREATE FUNCTION mk_not_null(text) RETURNS text
2762
    LANGUAGE sql IMMUTABLE
2763
    AS $_$
2764
SELECT COALESCE($1, '<NULL>')
2765
$_$;
2766

    
2767

    
2768
--
2769
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2770
--
2771

    
2772
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2773
    LANGUAGE sql IMMUTABLE
2774
    AS $_$
2775
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2776
util.qual_name((unnest).type), ''), '')
2777
FROM unnest($1)
2778
$_$;
2779

    
2780

    
2781
--
2782
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2783
--
2784

    
2785
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2786
    LANGUAGE sql IMMUTABLE
2787
    AS $_$
2788
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2789
$_$;
2790

    
2791

    
2792
--
2793
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2794
--
2795

    
2796
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2797
auto-appends util to the search_path to enable use of util operators
2798
';
2799

    
2800

    
2801
--
2802
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2803
--
2804

    
2805
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2806
    LANGUAGE sql STABLE
2807
    AS $_$
2808
SELECT COALESCE($$COMMENT ON $$||util.relation_type($1)||$$ $$||$1||$$ IS $$
2809
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2810
$_$;
2811

    
2812

    
2813
--
2814
-- Name: mk_set_relation_metadata(regclass); Type: FUNCTION; Schema: util; Owner: -
2815
--
2816

    
2817
CREATE FUNCTION mk_set_relation_metadata(relation regclass) RETURNS text
2818
    LANGUAGE sql STABLE
2819
    AS $_$
2820
SELECT util.show_grants_for($1)
2821
||util.show_set_comment($1)||$$
2822
$$
2823
$_$;
2824

    
2825

    
2826
--
2827
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2828
--
2829

    
2830
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2831
    LANGUAGE sql IMMUTABLE
2832
    AS $_$
2833
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2834
$_$;
2835

    
2836

    
2837
--
2838
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2839
--
2840

    
2841
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2842
    LANGUAGE sql IMMUTABLE
2843
    AS $_$
2844
/* debug_print_return_value() needed because this function is used with EXECUTE
2845
rather than util.eval() (in order to affect the calling function), so the
2846
search_path would not otherwise be printed */
2847
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2848
||$$ search_path TO $$||$1
2849
$_$;
2850

    
2851

    
2852
--
2853
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2854
--
2855

    
2856
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2857
    LANGUAGE sql
2858
    AS $_$
2859
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2860
$_$;
2861

    
2862

    
2863
--
2864
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2865
--
2866

    
2867
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2868
idempotent
2869
';
2870

    
2871

    
2872
--
2873
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2874
--
2875

    
2876
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2877
    LANGUAGE plpgsql STRICT
2878
    AS $_$
2879
DECLARE
2880
	view_qual_name text = util.qual_name(view_);
2881
BEGIN
2882
	EXECUTE $$
2883
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2884
  RETURNS SETOF $$||view_||$$ AS
2885
$BODY1$
2886
SELECT * FROM $$||view_qual_name||$$
2887
ORDER BY sort_col
2888
LIMIT $1 OFFSET $2
2889
$BODY1$
2890
  LANGUAGE sql STABLE
2891
  COST 100
2892
  ROWS 1000
2893
$$;
2894
	
2895
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2896
END;
2897
$_$;
2898

    
2899

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

    
2904
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2905
    LANGUAGE plpgsql STRICT
2906
    AS $_$
2907
DECLARE
2908
	view_qual_name text = util.qual_name(view_);
2909
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2910
BEGIN
2911
	EXECUTE $$
2912
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2913
  RETURNS integer AS
2914
$BODY1$
2915
SELECT $$||quote_ident(row_num_col)||$$
2916
FROM $$||view_qual_name||$$
2917
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2918
LIMIT 1
2919
$BODY1$
2920
  LANGUAGE sql STABLE
2921
  COST 100;
2922
$$;
2923
	
2924
	EXECUTE $$
2925
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2926
  RETURNS SETOF $$||view_||$$ AS
2927
$BODY1$
2928
SELECT * FROM $$||view_qual_name||$$
2929
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2930
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2931
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2932
ORDER BY $$||quote_ident(row_num_col)||$$
2933
$BODY1$
2934
  LANGUAGE sql STABLE
2935
  COST 100
2936
  ROWS 1000
2937
$$;
2938
	
2939
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2940
END;
2941
$_$;
2942

    
2943

    
2944
--
2945
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2946
--
2947

    
2948
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2949
    LANGUAGE plpgsql STRICT
2950
    AS $_$
2951
DECLARE
2952
	view_qual_name text = util.qual_name(view_);
2953
BEGIN
2954
	EXECUTE $$
2955
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2956
  RETURNS SETOF $$||view_||$$
2957
  SET enable_sort TO 'off'
2958
  AS
2959
$BODY1$
2960
SELECT * FROM $$||view_qual_name||$$($2, $3)
2961
$BODY1$
2962
  LANGUAGE sql STABLE
2963
  COST 100
2964
  ROWS 1000
2965
;
2966
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2967
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2968
If you want to run EXPLAIN and get expanded output, use the regular subset
2969
function instead. (When a config param is set on a function, EXPLAIN produces
2970
just a function scan.)
2971
';
2972
$$;
2973
END;
2974
$_$;
2975

    
2976

    
2977
--
2978
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2979
--
2980

    
2981
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2982
creates subset function which turns off enable_sort
2983
';
2984

    
2985

    
2986
--
2987
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2988
--
2989

    
2990
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2991
    LANGUAGE sql IMMUTABLE
2992
    AS $_$
2993
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2994
util.qual_name((unnest).type), ', '), '')
2995
FROM unnest($1)
2996
$_$;
2997

    
2998

    
2999
--
3000
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
3001
--
3002

    
3003
CREATE FUNCTION name(table_ regclass) RETURNS text
3004
    LANGUAGE sql STABLE
3005
    AS $_$
3006
SELECT relname::text FROM pg_class WHERE oid = $1
3007
$_$;
3008

    
3009

    
3010
--
3011
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
3012
--
3013

    
3014
CREATE FUNCTION name(type regtype) RETURNS text
3015
    LANGUAGE sql STABLE
3016
    AS $_$
3017
SELECT typname::text FROM pg_type WHERE oid = $1
3018
$_$;
3019

    
3020

    
3021
--
3022
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
3023
--
3024

    
3025
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
3026
    LANGUAGE sql IMMUTABLE
3027
    AS $_$
3028
SELECT octet_length($1) >= util.namedatalen() - $2
3029
$_$;
3030

    
3031

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

    
3036
CREATE FUNCTION namedatalen() RETURNS integer
3037
    LANGUAGE sql IMMUTABLE
3038
    AS $$
3039
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
3040
$$;
3041

    
3042

    
3043
--
3044
-- Name: new_world(); Type: FUNCTION; Schema: util; Owner: -
3045
--
3046

    
3047
CREATE FUNCTION new_world() RETURNS postgis.geography
3048
    LANGUAGE sql IMMUTABLE
3049
    SET search_path TO util
3050
    AS $$
3051
SELECT util.bounding_box(-56 ~ 83, 172 ~ -34)
3052
$$;
3053

    
3054

    
3055
--
3056
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
3057
--
3058

    
3059
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
3060
    LANGUAGE sql IMMUTABLE
3061
    AS $_$
3062
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
3063
$_$;
3064

    
3065

    
3066
--
3067
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
3068
--
3069

    
3070
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
3071
    LANGUAGE sql IMMUTABLE
3072
    AS $_$
3073
SELECT $1 IS NOT NULL
3074
$_$;
3075

    
3076

    
3077
--
3078
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
3079
--
3080

    
3081
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
3082
    LANGUAGE sql IMMUTABLE
3083
    AS $_$
3084
SELECT util.hstore($1, NULL) || '*=>*'
3085
$_$;
3086

    
3087

    
3088
--
3089
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
3090
--
3091

    
3092
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
3093
for use with _map()
3094
';
3095

    
3096

    
3097
--
3098
-- Name: numrange(range); Type: FUNCTION; Schema: util; Owner: -
3099
--
3100

    
3101
CREATE FUNCTION numrange(value range) RETURNS numrange
3102
    LANGUAGE sql IMMUTABLE
3103
    AS $_$
3104
SELECT numrange($1.lower, $1.upper, $1.bounds)
3105
$_$;
3106

    
3107

    
3108
--
3109
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
3110
--
3111

    
3112
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
3113
    LANGUAGE sql IMMUTABLE
3114
    AS $_$
3115
SELECT $2 + COALESCE($1, 0)
3116
$_$;
3117

    
3118

    
3119
--
3120
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
3121
--
3122

    
3123
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
3124
    LANGUAGE sql STABLE
3125
    AS $_$
3126
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
3127
$_$;
3128

    
3129

    
3130
--
3131
-- Name: pg_get_viewdef(regclass); Type: FUNCTION; Schema: util; Owner: -
3132
--
3133

    
3134
CREATE FUNCTION pg_get_viewdef(view_ regclass) RETURNS text
3135
    LANGUAGE sql STABLE
3136
    AS $_$
3137
SELECT util.view_def_to_orig(pg_catalog.pg_get_viewdef($1))
3138
$_$;
3139

    
3140

    
3141
--
3142
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3143
--
3144

    
3145
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
3146
    LANGUAGE sql
3147
    AS $_$
3148
SELECT util.eval($$INSERT INTO $$||$1||$$
3149
$$||util.ltrim_nl($2));
3150
-- make sure the created table has the correct estimated row count
3151
SELECT util.analyze_($1);
3152
$_$;
3153

    
3154

    
3155
--
3156
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
3157
--
3158

    
3159
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
3160
    LANGUAGE sql IMMUTABLE
3161
    AS $_$
3162
SELECT util.qual_name(util.schema($2), $1||util.name($2))
3163
$_$;
3164

    
3165

    
3166
--
3167
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3168
--
3169

    
3170
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
3171
    LANGUAGE sql
3172
    AS $_$
3173
SELECT util.set_comment($1, concat($2, util.comment($1)))
3174
$_$;
3175

    
3176

    
3177
--
3178
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
3179
--
3180

    
3181
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
3182
comment: must start and end with a newline
3183
';
3184

    
3185

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

    
3190
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
3191
    LANGUAGE sql IMMUTABLE
3192
    AS $_$
3193
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
3194
$_$;
3195

    
3196

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

    
3201
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
3202
    LANGUAGE sql STABLE
3203
    SET search_path TO pg_temp
3204
    AS $_$
3205
SELECT $1::text
3206
$_$;
3207

    
3208

    
3209
--
3210
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
3211
--
3212

    
3213
CREATE FUNCTION qual_name(type regtype) RETURNS text
3214
    LANGUAGE sql STABLE
3215
    SET search_path TO pg_temp
3216
    AS $_$
3217
SELECT $1::text
3218
$_$;
3219

    
3220

    
3221
--
3222
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
3223
--
3224

    
3225
COMMENT ON FUNCTION qual_name(type regtype) IS '
3226
a type''s schema-qualified name
3227
';
3228

    
3229

    
3230
--
3231
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
3232
--
3233

    
3234
CREATE FUNCTION qual_name(type unknown) RETURNS text
3235
    LANGUAGE sql STABLE
3236
    AS $_$
3237
SELECT util.qual_name($1::text::regtype)
3238
$_$;
3239

    
3240

    
3241
--
3242
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
3243
--
3244

    
3245
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
3246
    LANGUAGE sql IMMUTABLE
3247
    AS $_$
3248
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
3249
$_$;
3250

    
3251

    
3252
--
3253
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3254
--
3255

    
3256
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
3257
    LANGUAGE sql IMMUTABLE
3258
    AS $_$
3259
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
3260
$_$;
3261

    
3262

    
3263
--
3264
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
3265
--
3266

    
3267
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
3268
    LANGUAGE sql IMMUTABLE
3269
    AS $_$
3270
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
3271
$_$;
3272

    
3273

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

    
3278
CREATE FUNCTION raise(type text, msg text) RETURNS void
3279
    LANGUAGE sql IMMUTABLE
3280
    AS $_X$
3281
SELECT util.eval($$
3282
CREATE OR REPLACE FUNCTION pg_temp.__raise()
3283
  RETURNS void AS
3284
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
3285
$__BODY1$
3286
BEGIN
3287
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
3288
END;
3289
$__BODY1$
3290
  LANGUAGE plpgsql IMMUTABLE
3291
  COST 100;
3292
$$, verbose_ := false);
3293

    
3294
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
3295
$_X$;
3296

    
3297

    
3298
--
3299
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
3300
--
3301

    
3302
COMMENT ON FUNCTION raise(type text, msg text) IS '
3303
type: a log level from
3304
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
3305
or a condition name from
3306
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
3307
';
3308

    
3309

    
3310
--
3311
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
3312
--
3313

    
3314
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3315
    LANGUAGE sql IMMUTABLE
3316
    AS $_$
3317
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3318
$_$;
3319

    
3320

    
3321
--
3322
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3323
--
3324

    
3325
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3326
    LANGUAGE plpgsql IMMUTABLE STRICT
3327
    AS $$
3328
BEGIN
3329
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3330
END;
3331
$$;
3332

    
3333

    
3334
--
3335
-- Name: range(numeric, numeric); Type: FUNCTION; Schema: util; Owner: -
3336
--
3337

    
3338
CREATE FUNCTION range(lower numeric, upper numeric) RETURNS range
3339
    LANGUAGE sql IMMUTABLE
3340
    AS $_$
3341
SELECT ($1, $2, '[]')::util.range
3342
$_$;
3343

    
3344

    
3345
--
3346
-- Name: recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3347
--
3348

    
3349
CREATE FUNCTION recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
3350
    LANGUAGE plpgsql
3351
    AS $_$
3352
DECLARE
3353
	PG_EXCEPTION_DETAIL text;
3354
	restore_views_info util.restore_views_info;
3355
BEGIN
3356
	restore_views_info = util.save_drop_views(users);
3357
	
3358
	-- trigger the dependent_objects_still_exist exception
3359
	PERFORM util.eval(COALESCE(util.mk_drop_from_create(cmd), '')||cmd);
3360
		-- *not* CASCADE; it must trigger an exception
3361
	
3362
	PERFORM util.restore_views(restore_views_info);
3363
EXCEPTION
3364
WHEN dependent_objects_still_exist THEN
3365
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
3366
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
3367
	users = array(SELECT * FROM util.regexp_matches_group(
3368
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$'));
3369
		-- will be in forward dependency order
3370
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
3371
	PERFORM util.debug_print_var('users', users);
3372
	IF util.is_empty(users) THEN RAISE; END IF;
3373
	PERFORM util.recreate(cmd, users);
3374
END;
3375
$_$;
3376

    
3377

    
3378
--
3379
-- Name: FUNCTION recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
3380
--
3381

    
3382
COMMENT ON FUNCTION recreate(cmd text, users text[]) IS '
3383
the appropriate drop statement will be added automatically.
3384

    
3385
usage:
3386
SELECT util.recreate($$
3387
CREATE VIEW schema.main_view AS _;
3388

    
3389
-- manually restore views that need to be updated for the changes
3390
CREATE VIEW schema.dependent_view AS _;
3391
$$);
3392

    
3393
idempotent
3394

    
3395
users: not necessary to provide this because it will be autopopulated
3396
';
3397

    
3398

    
3399
--
3400
-- Name: recreate_view(regclass, text, text); Type: FUNCTION; Schema: util; Owner: -
3401
--
3402

    
3403
CREATE FUNCTION recreate_view(view_ regclass, view_query text DEFAULT NULL::text, dependent_view_changes text DEFAULT ''::text) RETURNS void
3404
    LANGUAGE sql
3405
    AS $_$
3406
SELECT util.recreate($$
3407
CREATE VIEW $$||$1||$$ AS 
3408
$$||COALESCE($2, pg_get_viewdef($1))||$$;
3409
$$||util.mk_set_relation_metadata($1)||$$
3410

    
3411
-- manually restore views that need to be updated for the changes
3412
$$||$3||$$
3413
$$);
3414
$_$;
3415

    
3416

    
3417
--
3418
-- Name: FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text); Type: COMMENT; Schema: util; Owner: -
3419
--
3420

    
3421
COMMENT ON FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text) IS '
3422
usage:
3423
SELECT util.recreate_view(''schema.main_view'', $$
3424
SELECT __
3425
$$, $$
3426
CREATE VIEW schema.dependent_view AS 
3427
__;
3428
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3429
$$);
3430

    
3431
if view has already been modified:
3432
SELECT util.recreate_view(''schema.main_view'', dependent_view_changes := $$
3433
CREATE VIEW schema.dependent_view AS 
3434
__;
3435
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3436
$$);
3437

    
3438
idempotent
3439
';
3440

    
3441

    
3442
--
3443
-- Name: regexp_match(text, text); Type: FUNCTION; Schema: util; Owner: -
3444
--
3445

    
3446
CREATE FUNCTION regexp_match(str text, re text) RETURNS text[]
3447
    LANGUAGE sql IMMUTABLE
3448
    AS $_$
3449
SELECT match FROM regexp_matches($1, $2) match LIMIT 1/*only 1st match*/
3450
$_$;
3451

    
3452

    
3453
--
3454
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3455
--
3456

    
3457
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3458
    LANGUAGE sql IMMUTABLE
3459
    AS $_$
3460
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3461
$_$;
3462

    
3463

    
3464
--
3465
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3466
--
3467

    
3468
CREATE FUNCTION regexp_quote(str text) RETURNS text
3469
    LANGUAGE sql IMMUTABLE
3470
    AS $_$
3471
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3472
$_$;
3473

    
3474

    
3475
--
3476
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
3477
--
3478

    
3479
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3480
    LANGUAGE sql IMMUTABLE
3481
    AS $_$
3482
SELECT (CASE WHEN right($1, 1) = ')'
3483
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3484
$_$;
3485

    
3486

    
3487
--
3488
-- Name: relation_exists(text); Type: FUNCTION; Schema: util; Owner: -
3489
--
3490

    
3491
CREATE FUNCTION relation_exists(relation text) RETURNS boolean
3492
    LANGUAGE sql STABLE
3493
    AS $_$
3494
SELECT $1 IS NOT NULL AND util.is_castable($1, NULL::regclass)
3495
$_$;
3496

    
3497

    
3498
--
3499
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3500
--
3501

    
3502
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3503
    LANGUAGE sql STABLE
3504
    AS $_$
3505
SELECT util.relation_type(util.relation_type_char($1))
3506
$_$;
3507

    
3508

    
3509
--
3510
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3511
--
3512

    
3513
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3514
    LANGUAGE sql IMMUTABLE
3515
    AS $_$
3516
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3517
$_$;
3518

    
3519

    
3520
--
3521
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3522
--
3523

    
3524
CREATE FUNCTION relation_type(type regtype) RETURNS text
3525
    LANGUAGE sql IMMUTABLE
3526
    AS $$
3527
SELECT 'TYPE'::text
3528
$$;
3529

    
3530

    
3531
--
3532
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
3533
--
3534

    
3535
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3536
    LANGUAGE sql STABLE
3537
    AS $_$
3538
SELECT relkind FROM pg_class WHERE oid = $1
3539
$_$;
3540

    
3541

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

    
3546
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3547
    LANGUAGE sql
3548
    AS $_$
3549
/* can't have in_table/out_table inherit from *each other*, because inheritance
3550
also causes the rows of the parent table to be included in the child table.
3551
instead, they need to inherit from a common, empty table. */
3552
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3553
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3554
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3555
SELECT util.inherit($2, $4);
3556
SELECT util.inherit($3, $4);
3557

    
3558
SELECT util.rematerialize_query($1, $$
3559
SELECT * FROM util.diff(
3560
  $$||util.quote_typed($2)||$$
3561
, $$||util.quote_typed($3)||$$
3562
, NULL::$$||$4||$$)
3563
$$);
3564

    
3565
/* the table unfortunately cannot be *materialized* in human-readable form,
3566
because this would create column name collisions between the two sides */
3567
SELECT util.prepend_comment($1, '
3568
to view this table in human-readable form (with each side''s tuple column
3569
expanded to its component fields):
3570
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3571

    
3572
to display NULL values that are extra or missing:
3573
SELECT * FROM '||$1||';
3574
');
3575
$_$;
3576

    
3577

    
3578
--
3579
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3580
--
3581

    
3582
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3583
type_table (*required*): table to create as the shared base type
3584
';
3585

    
3586

    
3587
--
3588
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3589
--
3590

    
3591
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3592
    LANGUAGE sql
3593
    AS $_$
3594
SELECT util.drop_table($1);
3595
SELECT util.materialize_query($1, $2);
3596
$_$;
3597

    
3598

    
3599
--
3600
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3601
--
3602

    
3603
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3604
idempotent, but repeats action each time
3605
';
3606

    
3607

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

    
3612
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3613
    LANGUAGE sql
3614
    AS $_$
3615
SELECT util.drop_table($1);
3616
SELECT util.materialize_view($1, $2);
3617
$_$;
3618

    
3619

    
3620
--
3621
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3622
--
3623

    
3624
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3625
idempotent, but repeats action each time
3626
';
3627

    
3628

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

    
3633
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3634
    LANGUAGE sql
3635
    AS $_$
3636
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3637
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3638
FROM util.col_names($1::text::regtype) f (name);
3639
SELECT NULL::void; -- don't fold away functions called in previous query
3640
$_$;
3641

    
3642

    
3643
--
3644
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3645
--
3646

    
3647
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3648
idempotent
3649
';
3650

    
3651

    
3652
--
3653
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3654
--
3655

    
3656
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3657
    LANGUAGE sql
3658
    AS $_$
3659
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3660
included in the debug SQL */
3661
SELECT util.rename_relation(util.qual_name($1), $2)
3662
$_$;
3663

    
3664

    
3665
--
3666
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3667
--
3668

    
3669
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3670
    LANGUAGE sql
3671
    AS $_$
3672
/* 'ALTER TABLE can be used with views too'
3673
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3674
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3675
||quote_ident($2))
3676
$_$;
3677

    
3678

    
3679
--
3680
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3681
--
3682

    
3683
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3684
idempotent
3685
';
3686

    
3687

    
3688
--
3689
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3690
--
3691

    
3692
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3693
    LANGUAGE sql IMMUTABLE
3694
    AS $_$
3695
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3696
$_$;
3697

    
3698

    
3699
--
3700
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3701
--
3702

    
3703
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3704
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 
3705
';
3706

    
3707

    
3708
--
3709
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3710
--
3711

    
3712
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3713
    LANGUAGE sql
3714
    AS $_$
3715
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3716
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3717
SELECT util.set_col_names($1, $2);
3718
$_$;
3719

    
3720

    
3721
--
3722
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3723
--
3724

    
3725
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3726
idempotent.
3727
alters the names table, so it will need to be repopulated after running this function.
3728
';
3729

    
3730

    
3731
--
3732
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3733
--
3734

    
3735
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3736
    LANGUAGE sql
3737
    AS $_$
3738
SELECT util.drop_table($1);
3739
SELECT util.mk_map_table($1);
3740
$_$;
3741

    
3742

    
3743
--
3744
-- Name: restore_views(restore_views_info); Type: FUNCTION; Schema: util; Owner: -
3745
--
3746

    
3747
CREATE FUNCTION restore_views(restore_views_info) RETURNS void
3748
    LANGUAGE sql
3749
    AS $_$
3750
SELECT util.debug_print_var('views', $1);
3751
SELECT util.create_if_not_exists((view_).def, (view_).path)
3752
	/* need to specify view name for manual existence check, in case view def
3753
	becomes invalid, which would produce nonstandard (uncatchable) exception */
3754
FROM unnest($1.views) view_; -- in forward dependency order
3755
	/* create_if_not_exists() rather than eval(), because cmd might manually
3756
	re-create a deleted dependent view, causing it to already exist */
3757
SELECT NULL::void; -- don't fold away functions called in previous query
3758
$_$;
3759

    
3760

    
3761
--
3762
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3763
--
3764

    
3765
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3766
    LANGUAGE sql
3767
    AS $_$
3768
SELECT util.drop_column($1, $2, force := true)
3769
$_$;
3770

    
3771

    
3772
--
3773
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3774
--
3775

    
3776
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3777
    LANGUAGE sql IMMUTABLE
3778
    AS $_$
3779
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3780
$_$;
3781

    
3782

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

    
3787
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3788
    LANGUAGE sql IMMUTABLE
3789
    AS $_$
3790
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3791
ELSE util.mk_set_search_path(for_printing := true)||$$;
3792
$$ END)||$1
3793
$_$;
3794

    
3795

    
3796
--
3797
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3798
--
3799

    
3800
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3801
    LANGUAGE plpgsql STRICT
3802
    AS $$
3803
DECLARE
3804
	result text = NULL;
3805
BEGIN
3806
	BEGIN
3807
		result = util.show_create_view(view_, replace := false);
3808
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3809
			(eg. invalid_table_definition), instead of the standard
3810
			duplicate_table exception caught by util.create_if_not_exists() */
3811
		PERFORM util.drop_view(view_);
3812
	EXCEPTION
3813
		WHEN undefined_table THEN NULL;
3814
	END;
3815
	RETURN result;
3816
END;
3817
$$;
3818

    
3819

    
3820
--
3821
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3822
--
3823

    
3824
CREATE FUNCTION save_drop_views(views text[]) RETURNS restore_views_info
3825
    LANGUAGE sql
3826
    AS $_$
3827
SELECT ROW(/*return in forward dependency order*/util.array_reverse(array(
3828
SELECT (view_, util.save_drop_view(view_))::util.db_item
3829
FROM unnest(/*drop in reverse dependency order*/util.array_reverse($1)) view_
3830
)))::util.restore_views_info
3831
$_$;
3832

    
3833

    
3834
--
3835
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3836
--
3837

    
3838
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3839
    LANGUAGE sql STABLE
3840
    AS $_$
3841
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3842
$_$;
3843

    
3844

    
3845
--
3846
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3847
--
3848

    
3849
CREATE FUNCTION schema(table_ regclass) RETURNS text
3850
    LANGUAGE sql STABLE
3851
    AS $_$
3852
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3853
$_$;
3854

    
3855

    
3856
--
3857
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3858
--
3859

    
3860
CREATE FUNCTION schema(type regtype) RETURNS text
3861
    LANGUAGE sql STABLE
3862
    AS $_$
3863
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3864
$_$;
3865

    
3866

    
3867
--
3868
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3869
--
3870

    
3871
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3872
    LANGUAGE sql STABLE
3873
    AS $_$
3874
SELECT util.schema(pg_typeof($1))
3875
$_$;
3876

    
3877

    
3878
--
3879
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3880
--
3881

    
3882
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3883
    LANGUAGE sql STABLE
3884
    AS $_$
3885
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3886
$_$;
3887

    
3888

    
3889
--
3890
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3891
--
3892

    
3893
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3894
a schema bundle is a group of schemas with a common prefix
3895
';
3896

    
3897

    
3898
--
3899
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3900
--
3901

    
3902
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3903
    LANGUAGE sql
3904
    AS $_$
3905
SELECT util.schema_rename(old_schema,
3906
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3907
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3908
SELECT NULL::void; -- don't fold away functions called in previous query
3909
$_$;
3910

    
3911

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

    
3916
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3917
    LANGUAGE plpgsql
3918
    AS $$
3919
BEGIN
3920
	-- don't schema_bundle_rm() the schema_bundle to keep!
3921
	IF replace = with_ THEN RETURN; END IF;
3922
	
3923
	PERFORM util.schema_bundle_rm(replace);
3924
	PERFORM util.schema_bundle_rename(with_, replace);
3925
END;
3926
$$;
3927

    
3928

    
3929
--
3930
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3931
--
3932

    
3933
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3934
    LANGUAGE sql
3935
    AS $_$
3936
SELECT util.schema_rm(schema)
3937
FROM util.schema_bundle_get_schemas($1) f (schema);
3938
SELECT NULL::void; -- don't fold away functions called in previous query
3939
$_$;
3940

    
3941

    
3942
--
3943
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3944
--
3945

    
3946
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3947
    LANGUAGE sql STABLE
3948
    AS $_$
3949
SELECT quote_ident(util.schema($1))
3950
$_$;
3951

    
3952

    
3953
--
3954
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3955
--
3956

    
3957
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3958
    LANGUAGE sql IMMUTABLE
3959
    AS $_$
3960
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3961
$_$;
3962

    
3963

    
3964
--
3965
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3966
--
3967

    
3968
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3969
    LANGUAGE sql STABLE
3970
    AS $_$
3971
SELECT oid FROM pg_namespace WHERE nspname = $1
3972
$_$;
3973

    
3974

    
3975
--
3976
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3977
--
3978

    
3979
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3980
    LANGUAGE sql IMMUTABLE
3981
    AS $_$
3982
SELECT util.schema_regexp(schema_anchor := $1)
3983
$_$;
3984

    
3985

    
3986
--
3987
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3988
--
3989

    
3990
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3991
    LANGUAGE sql IMMUTABLE
3992
    AS $_$
3993
SELECT util.str_equality_regexp(util.schema($1))
3994
$_$;
3995

    
3996

    
3997
--
3998
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3999
--
4000

    
4001
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
4002
    LANGUAGE sql
4003
    AS $_$
4004
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
4005
$_$;
4006

    
4007

    
4008
--
4009
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
4010
--
4011

    
4012
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
4013
    LANGUAGE plpgsql
4014
    AS $$
4015
BEGIN
4016
	-- don't schema_rm() the schema to keep!
4017
	IF replace = with_ THEN RETURN; END IF;
4018
	
4019
	PERFORM util.schema_rm(replace);
4020
	PERFORM util.schema_rename(with_, replace);
4021
END;
4022
$$;
4023

    
4024

    
4025
--
4026
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
4027
--
4028

    
4029
CREATE FUNCTION schema_rm(schema text) RETURNS void
4030
    LANGUAGE sql
4031
    AS $_$
4032
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
4033
$_$;
4034

    
4035

    
4036
--
4037
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
4038
--
4039

    
4040
CREATE FUNCTION search_path_append(schemas text) RETURNS void
4041
    LANGUAGE sql
4042
    AS $_$
4043
SELECT util.eval(
4044
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
4045
$_$;
4046

    
4047

    
4048
--
4049
-- Name: seq__create(text, integer); Type: FUNCTION; Schema: util; Owner: -
4050
--
4051

    
4052
CREATE FUNCTION seq__create(seq text, start integer DEFAULT 0) RETURNS void
4053
    LANGUAGE sql
4054
    AS $_$
4055
SELECT util.create_if_not_exists($$CREATE SEQUENCE $$||$1||$$ MINVALUE $$||$2,
4056
$1)
4057
$_$;
4058

    
4059

    
4060
--
4061
-- Name: FUNCTION seq__create(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
4062
--
4063

    
4064
COMMENT ON FUNCTION seq__create(seq text, start integer) IS '
4065
idempotent
4066
';
4067

    
4068

    
4069
--
4070
-- Name: seq__reset(text, integer); Type: FUNCTION; Schema: util; Owner: -
4071
--
4072

    
4073
CREATE FUNCTION seq__reset(seq text, start integer DEFAULT 0) RETURNS void
4074
    LANGUAGE sql
4075
    AS $_$
4076
SELECT util.seq__create($1, $2);
4077
SELECT util.eval($$ALTER SEQUENCE $$||$1||$$ RESTART$$);
4078
$_$;
4079

    
4080

    
4081
--
4082
-- Name: FUNCTION seq__reset(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
4083
--
4084

    
4085
COMMENT ON FUNCTION seq__reset(seq text, start integer) IS '
4086
creates sequence if doesn''t exist
4087

    
4088
idempotent
4089

    
4090
start: *note*: only used if sequence doesn''t exist
4091
';
4092

    
4093

    
4094
--
4095
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
4096
--
4097

    
4098
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
4099
    LANGUAGE plpgsql STRICT
4100
    AS $_$
4101
DECLARE
4102
    old text[] = ARRAY(SELECT util.col_names(table_));
4103
    new text[] = ARRAY(SELECT util.map_values(names));
4104
BEGIN
4105
    old = old[1:array_length(new, 1)]; -- truncate to same length
4106
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
4107
||$$ TO $$||quote_ident(value))
4108
    FROM each(hstore(old, new))
4109
    WHERE value != key -- not same name
4110
    ;
4111
END;
4112
$_$;
4113

    
4114

    
4115
--
4116
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
4117
--
4118

    
4119
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
4120
idempotent
4121
';
4122

    
4123

    
4124
--
4125
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
4126
--
4127

    
4128
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
4129
    LANGUAGE plpgsql STRICT
4130
    AS $_$
4131
DECLARE
4132
	row_ util.map;
4133
BEGIN
4134
	-- rename any metadata cols rather than re-adding them with new names
4135
	BEGIN
4136
		PERFORM util.set_col_names(table_, names);
4137
	EXCEPTION
4138
		WHEN array_subscript_error THEN -- selective suppress
4139
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
4140
				-- metadata cols not yet added
4141
			ELSE RAISE;
4142
			END IF;
4143
	END;
4144
	
4145
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
4146
	LOOP
4147
		PERFORM util.mk_const_col((table_, row_."to"),
4148
			substring(row_."from" from 2));
4149
	END LOOP;
4150
	
4151
	PERFORM util.set_col_names(table_, names);
4152
END;
4153
$_$;
4154

    
4155

    
4156
--
4157
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
4158
--
4159

    
4160
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
4161
idempotent.
4162
the metadata mappings must be *last* in the names table.
4163
';
4164

    
4165

    
4166
--
4167
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
4168
--
4169

    
4170
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
4171
    LANGUAGE sql
4172
    AS $_$
4173
SELECT util.eval(COALESCE(
4174
$$ALTER TABLE $$||$1||$$
4175
$$||(
4176
	SELECT
4177
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
4178
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
4179
, $$)
4180
	FROM
4181
	(
4182
		SELECT
4183
		  quote_ident(col_name) AS col_name_sql
4184
		, util.col_type(($1, col_name)) AS curr_type
4185
		, type AS target_type
4186
		FROM unnest($2)
4187
	) s
4188
	WHERE curr_type != target_type
4189
), ''))
4190
$_$;
4191

    
4192

    
4193
--
4194
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
4195
--
4196

    
4197
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
4198
idempotent
4199
';
4200

    
4201

    
4202
--
4203
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4204
--
4205

    
4206
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
4207
    LANGUAGE sql
4208
    AS $_$
4209
SELECT util.eval(util.mk_set_comment($1, $2))
4210
$_$;
4211

    
4212

    
4213
--
4214
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
4215
--
4216

    
4217
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
4218
    LANGUAGE sql
4219
    AS $_$
4220
SELECT util.eval(util.mk_set_search_path($1, $2))
4221
$_$;
4222

    
4223

    
4224
--
4225
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4226
--
4227

    
4228
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
4229
    LANGUAGE sql STABLE
4230
    AS $_$
4231
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
4232
||$1||$$ AS
4233
$$||util.pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
4234
$$||util.mk_set_relation_metadata($1)
4235
$_$;
4236

    
4237

    
4238
--
4239
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
4240
--
4241

    
4242
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
4243
    LANGUAGE sql STABLE
4244
    AS $_$
4245
SELECT string_agg(cmd, '')
4246
FROM
4247
(
4248
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
4249
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
4250
$$ ELSE '' END) AS cmd
4251
	FROM util.grants_users() f (user_)
4252
) s
4253
$_$;
4254

    
4255

    
4256
--
4257
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
4258
--
4259

    
4260
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
4261
    LANGUAGE sql STABLE
4262
    AS $_$
4263
SELECT oid FROM pg_class
4264
WHERE relkind = ANY($3) AND relname ~ $1
4265
AND util.schema_matches(util.schema(relnamespace), $2)
4266
ORDER BY relname
4267
$_$;
4268

    
4269

    
4270
--
4271
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
4272
--
4273

    
4274
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
4275
    LANGUAGE sql STABLE
4276
    AS $_$
4277
SELECT util.mk_set_comment($1, util.comment($1))
4278
$_$;
4279

    
4280

    
4281
--
4282
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4283
--
4284

    
4285
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
4286
    LANGUAGE sql STABLE
4287
    AS $_$
4288
SELECT oid
4289
FROM pg_type
4290
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
4291
ORDER BY typname
4292
$_$;
4293

    
4294

    
4295
--
4296
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4297
--
4298

    
4299
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
4300
    LANGUAGE sql STABLE
4301
    AS $_$
4302
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
4303
$_$;
4304

    
4305

    
4306
--
4307
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
4308
--
4309

    
4310
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
4311
    LANGUAGE sql IMMUTABLE
4312
    AS $_$
4313
SELECT '^'||util.regexp_quote($1)||'$'
4314
$_$;
4315

    
4316

    
4317
--
4318
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
4319
--
4320

    
4321
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
4322
    LANGUAGE plpgsql STABLE STRICT
4323
    AS $_$
4324
DECLARE
4325
    hstore hstore;
4326
BEGIN
4327
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
4328
        table_||$$))$$ INTO STRICT hstore;
4329
    RETURN hstore;
4330
END;
4331
$_$;
4332

    
4333

    
4334
--
4335
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4336
--
4337

    
4338
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
4339
    LANGUAGE sql STABLE
4340
    AS $_$
4341
SELECT COUNT(*) > 0 FROM pg_constraint
4342
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
4343
$_$;
4344

    
4345

    
4346
--
4347
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4348
--
4349

    
4350
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
4351
gets whether a status flag is set by the presence of a table constraint
4352
';
4353

    
4354

    
4355
--
4356
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4357
--
4358

    
4359
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
4360
    LANGUAGE sql
4361
    AS $_$
4362
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
4363
||quote_ident($2)||$$ CHECK (true)$$)
4364
$_$;
4365

    
4366

    
4367
--
4368
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4369
--
4370

    
4371
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
4372
stores a status flag by the presence of a table constraint.
4373
idempotent.
4374
';
4375

    
4376

    
4377
--
4378
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
4379
--
4380

    
4381
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
4382
    LANGUAGE sql STABLE
4383
    AS $_$
4384
SELECT util.table_flag__get($1, 'nulls_mapped')
4385
$_$;
4386

    
4387

    
4388
--
4389
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4390
--
4391

    
4392
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
4393
gets whether a table''s NULL-equivalent strings have been replaced with NULL
4394
';
4395

    
4396

    
4397
--
4398
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
4399
--
4400

    
4401
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
4402
    LANGUAGE sql
4403
    AS $_$
4404
SELECT util.table_flag__set($1, 'nulls_mapped')
4405
$_$;
4406

    
4407

    
4408
--
4409
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4410
--
4411

    
4412
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
4413
sets that a table''s NULL-equivalent strings have been replaced with NULL.
4414
idempotent.
4415
';
4416

    
4417

    
4418
--
4419
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
4420
--
4421

    
4422
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
4423
    LANGUAGE sql
4424
    AS $_$
4425
-- save data before truncating main table
4426
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
4427

    
4428
-- repopulate main table w/ copies column
4429
SELECT util.truncate($1);
4430
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
4431
SELECT util.populate_table($1, $$
4432
SELECT (table_).*, copies
4433
FROM (
4434
	SELECT table_, COUNT(*) AS copies
4435
	FROM pg_temp.__copy table_
4436
	GROUP BY table_
4437
) s
4438
$$);
4439

    
4440
-- delete temp table so it doesn't stay around until end of connection
4441
SELECT util.drop_table('pg_temp.__copy');
4442
$_$;
4443

    
4444

    
4445
--
4446
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
4447
--
4448

    
4449
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
4450
    LANGUAGE plpgsql STRICT
4451
    AS $_$
4452
DECLARE
4453
    row record;
4454
BEGIN
4455
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
4456
    LOOP
4457
        IF row.global_name != row.name THEN
4458
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
4459
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
4460
        END IF;
4461
    END LOOP;
4462
END;
4463
$_$;
4464

    
4465

    
4466
--
4467
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4468
--
4469

    
4470
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
4471
idempotent
4472
';
4473

    
4474

    
4475
--
4476
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4477
--
4478

    
4479
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
4480
    LANGUAGE sql
4481
    AS $_$
4482
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
4483
SELECT NULL::void; -- don't fold away functions called in previous query
4484
$_$;
4485

    
4486

    
4487
--
4488
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
4489
--
4490

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

    
4494
by default, cascadingly drops dependent columns so that they don''t prevent
4495
trim() from succeeding. note that this requires the dependent columns to then be
4496
manually re-created.
4497

    
4498
idempotent
4499
';
4500

    
4501

    
4502
--
4503
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4504
--
4505

    
4506
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4507
    LANGUAGE plpgsql STRICT
4508
    AS $_$
4509
BEGIN
4510
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4511
END;
4512
$_$;
4513

    
4514

    
4515
--
4516
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4517
--
4518

    
4519
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4520
idempotent
4521
';
4522

    
4523

    
4524
--
4525
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4526
--
4527

    
4528
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4529
    LANGUAGE sql IMMUTABLE
4530
    AS $_$
4531
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4532
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4533
$_$;
4534

    
4535

    
4536
--
4537
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4538
--
4539

    
4540
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4541
    LANGUAGE plpgsql IMMUTABLE
4542
    AS $$
4543
BEGIN
4544
	/* need explicit cast because some types not implicitly-castable, and also
4545
	to make the cast happen inside the try block. (*implicit* casts to the
4546
	return type happen at the end of the function, outside any block.) */
4547
	RETURN util.cast(value, ret_type_null);
4548
EXCEPTION
4549
WHEN   data_exception
4550
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
4551
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
4552
	THEN
4553
	PERFORM util.raise('WARNING', SQLERRM);
4554
	RETURN NULL;
4555
END;
4556
$$;
4557

    
4558

    
4559
--
4560
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4561
--
4562

    
4563
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4564
ret_type_null: NULL::ret_type
4565
';
4566

    
4567

    
4568
--
4569
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4570
--
4571

    
4572
CREATE FUNCTION try_create(sql text) RETURNS void
4573
    LANGUAGE plpgsql STRICT
4574
    AS $$
4575
BEGIN
4576
	PERFORM util.eval(sql);
4577
EXCEPTION
4578
WHEN   not_null_violation
4579
		/* trying to add NOT NULL column to parent table, which cascades to
4580
		child table whose values for the new column will be NULL */
4581
	OR wrong_object_type -- trying to alter a view's columns
4582
	OR undefined_column
4583
	OR duplicate_column
4584
THEN NULL;
4585
WHEN datatype_mismatch THEN
4586
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4587
	ELSE RAISE; -- rethrow
4588
	END IF;
4589
END;
4590
$$;
4591

    
4592

    
4593
--
4594
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4595
--
4596

    
4597
COMMENT ON FUNCTION try_create(sql text) IS '
4598
idempotent
4599
';
4600

    
4601

    
4602
--
4603
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4604
--
4605

    
4606
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4607
    LANGUAGE sql
4608
    AS $_$
4609
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4610
$_$;
4611

    
4612

    
4613
--
4614
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4615
--
4616

    
4617
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4618
idempotent
4619
';
4620

    
4621

    
4622
--
4623
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4624
--
4625

    
4626
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4627
    LANGUAGE sql IMMUTABLE
4628
    AS $_$
4629
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4630
$_$;
4631

    
4632

    
4633
--
4634
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4635
--
4636

    
4637
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4638
a type''s NOT NULL qualifier
4639
';
4640

    
4641

    
4642
--
4643
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4644
--
4645

    
4646
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4647
    LANGUAGE sql STABLE
4648
    AS $_$
4649
SELECT (attname::text, atttypid)::util.col_cast
4650
FROM pg_attribute
4651
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4652
ORDER BY attnum
4653
$_$;
4654

    
4655

    
4656
--
4657
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4658
--
4659

    
4660
CREATE FUNCTION typeof(value anyelement) RETURNS text
4661
    LANGUAGE sql IMMUTABLE
4662
    AS $_$
4663
SELECT util.qual_name(pg_typeof($1))
4664
$_$;
4665

    
4666

    
4667
--
4668
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4669
--
4670

    
4671
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4672
    LANGUAGE plpgsql STABLE
4673
    AS $_$
4674
DECLARE
4675
    type regtype;
4676
BEGIN
4677
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4678
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4679
    RETURN type;
4680
END;
4681
$_$;
4682

    
4683

    
4684
--
4685
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4686
--
4687

    
4688
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4689
    LANGUAGE sql
4690
    AS $_$
4691
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4692
$_$;
4693

    
4694

    
4695
--
4696
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4697
--
4698

    
4699
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4700
auto-appends util to the search_path to enable use of util operators
4701
';
4702

    
4703

    
4704
--
4705
-- Name: view_def_to_orig(text); Type: FUNCTION; Schema: util; Owner: -
4706
--
4707

    
4708
CREATE FUNCTION view_def_to_orig(view_def text) RETURNS text
4709
    LANGUAGE sql IMMUTABLE
4710
    AS $_$
4711
SELECT CASE
4712
WHEN util.view_is_subset($1) THEN $1
4713
	-- list of cols from the same table is not an expanded * expression
4714
ELSE
4715
regexp_replace(
4716
regexp_replace(
4717
$1
4718
,
4719
/* unexpand expanded * expressions. any list of 6+ cols from the same table is
4720
treated as a * expression. */
4721
'((?:"[^"\s]+"|\w+)\.)(?:"[^"\s]+"|\w+)'||
4722
	/* 1st col, which lacks separator before.
4723
	*note*: can't prepend \y because it considers only \w chars, not " */
4724
'(,[[:blank:]]*
4725
[[:blank:]]*)\1(?:"[^"\s]+"|\w+)'|| -- 2nd col, which has separator before
4726
'(?:\2\1(?:"[^"\s]+"|\w+)){4,}', -- later cols, w/ same table name and separator
4727
'\1*'/*prefix w/ table*/,
4728
'g')
4729
,
4730
/* merge .* expressions resulting from a SELECT * of a join. any list of
4731
multiple .* expressions is treated as a SELECT * . */
4732
'(?:"[^"\s]+"|\w+)\.\*'||
4733
	/* 1st table, which lacks separator before.
4734
	*note*: can't prepend \y because it considers only \w chars, not " */
4735
'(,[[:blank:]]*
4736
[[:blank:]]*)(?:"[^"\s]+"|\w+)\.\*'|| -- 2nd table, which has separator before
4737
'(?:\1(?:"[^"\s]+"|\w+)\.\*)*', -- later tables, w/ same separator
4738
'*',
4739
'g')
4740
END
4741
$_$;
4742

    
4743

    
4744
--
4745
-- Name: view_is_automatically_updatable(text); Type: FUNCTION; Schema: util; Owner: -
4746
--
4747

    
4748
CREATE FUNCTION view_is_automatically_updatable(view_def text) RETURNS boolean
4749
    LANGUAGE sql IMMUTABLE
4750
    AS $_$
4751
SELECT $1 !~ '\y(?:JOIN|WITH|DISTINCT|GROUP BY|HAVING|LIMIT|OFFSET)\y'
4752
	/* from http://www.postgresql.org/docs/9.3/static/sql-createview.html#SQL-CREATEVIEW-UPDATABLE-VIEWS */
4753
$_$;
4754

    
4755

    
4756
--
4757
-- Name: view_is_subset(text); Type: FUNCTION; Schema: util; Owner: -
4758
--
4759

    
4760
CREATE FUNCTION view_is_subset(view_def text) RETURNS boolean
4761
    LANGUAGE sql IMMUTABLE
4762
    AS $_$
4763
SELECT util.view_is_automatically_updatable($1)
4764
$_$;
4765

    
4766

    
4767
--
4768
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4769
--
4770

    
4771
CREATE AGGREGATE all_same(anyelement) (
4772
    SFUNC = all_same_transform,
4773
    STYPE = anyarray,
4774
    FINALFUNC = all_same_final
4775
);
4776

    
4777

    
4778
--
4779
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4780
--
4781

    
4782
COMMENT ON AGGREGATE all_same(anyelement) IS '
4783
includes NULLs in comparison
4784
';
4785

    
4786

    
4787
--
4788
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4789
--
4790

    
4791
CREATE AGGREGATE join_strs(text, text) (
4792
    SFUNC = join_strs_transform,
4793
    STYPE = text
4794
);
4795

    
4796

    
4797
--
4798
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4799
--
4800

    
4801
CREATE OPERATOR %== (
4802
    PROCEDURE = keys_eq,
4803
    LEFTARG = anyelement,
4804
    RIGHTARG = anyelement
4805
);
4806

    
4807

    
4808
--
4809
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4810
--
4811

    
4812
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4813
returns whether the map-keys of the compared values are the same
4814
(mnemonic: % is the Perl symbol for a hash map)
4815

    
4816
should be overridden for types that store both keys and values
4817

    
4818
used in a FULL JOIN to select which columns to join on
4819
';
4820

    
4821

    
4822
--
4823
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4824
--
4825

    
4826
CREATE OPERATOR -> (
4827
    PROCEDURE = map_get,
4828
    LEFTARG = regclass,
4829
    RIGHTARG = text
4830
);
4831

    
4832

    
4833
--
4834
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4835
--
4836

    
4837
CREATE OPERATOR => (
4838
    PROCEDURE = hstore,
4839
    LEFTARG = text[],
4840
    RIGHTARG = text
4841
);
4842

    
4843

    
4844
--
4845
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4846
--
4847

    
4848
COMMENT ON OPERATOR => (text[], text) IS '
4849
usage: array[''key1'', ...]::text[] => ''value''
4850
';
4851

    
4852

    
4853
--
4854
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4855
--
4856

    
4857
CREATE OPERATOR ?*>= (
4858
    PROCEDURE = is_populated_more_often_than,
4859
    LEFTARG = anyelement,
4860
    RIGHTARG = anyelement
4861
);
4862

    
4863

    
4864
--
4865
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4866
--
4867

    
4868
CREATE OPERATOR ?>= (
4869
    PROCEDURE = is_more_complete_than,
4870
    LEFTARG = anyelement,
4871
    RIGHTARG = anyelement
4872
);
4873

    
4874

    
4875
--
4876
-- Name: @; Type: OPERATOR; Schema: util; Owner: -
4877
--
4878

    
4879
CREATE OPERATOR @ (
4880
    PROCEDURE = contained_within__no_dateline,
4881
    LEFTARG = postgis.geometry,
4882
    RIGHTARG = postgis.geometry
4883
);
4884

    
4885

    
4886
--
4887
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4888
--
4889

    
4890
CREATE OPERATOR ||% (
4891
    PROCEDURE = concat_esc,
4892
    LEFTARG = text,
4893
    RIGHTARG = text
4894
);
4895

    
4896

    
4897
--
4898
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4899
--
4900

    
4901
COMMENT ON OPERATOR ||% (text, text) IS '
4902
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4903
';
4904

    
4905

    
4906
--
4907
-- Name: ~; Type: OPERATOR; Schema: util; Owner: -
4908
--
4909

    
4910
CREATE OPERATOR ~ (
4911
    PROCEDURE = range,
4912
    LEFTARG = numeric,
4913
    RIGHTARG = numeric
4914
);
4915

    
4916

    
4917
--
4918
-- Name: ~@; Type: OPERATOR; Schema: util; Owner: -
4919
--
4920

    
4921
CREATE OPERATOR ~@ (
4922
    PROCEDURE = contained_within_approx,
4923
    LEFTARG = postgis.geography,
4924
    RIGHTARG = postgis.geography
4925
);
4926

    
4927

    
4928
--
4929
-- Name: OPERATOR ~@ (postgis.geography, postgis.geography); Type: COMMENT; Schema: util; Owner: -
4930
--
4931

    
4932
COMMENT ON OPERATOR ~@ (postgis.geography, postgis.geography) IS '
4933
can''t use && because it only compares 2D bounding boxes (which are geometry
4934
objects that do not support geocoordinate wraparound)
4935
';
4936

    
4937

    
4938
--
4939
-- Name: ~@; Type: OPERATOR; Schema: util; Owner: -
4940
--
4941

    
4942
CREATE OPERATOR ~@ (
4943
    PROCEDURE = contained_within_approx,
4944
    LEFTARG = geocoord,
4945
    RIGHTARG = postgis.geography
4946
);
4947

    
4948

    
4949
--
4950
-- Name: ~@; Type: OPERATOR; Schema: util; Owner: -
4951
--
4952

    
4953
CREATE OPERATOR ~@ (
4954
    PROCEDURE = contained_within__no_dateline,
4955
    LEFTARG = geocoord,
4956
    RIGHTARG = postgis.geometry
4957
);
4958

    
4959

    
4960
SET search_path = pg_catalog;
4961

    
4962
--
4963
-- Name: CAST (util.range AS numrange); Type: CAST; Schema: pg_catalog; Owner: -
4964
--
4965

    
4966
CREATE CAST (util.range AS numrange) WITH FUNCTION util.numrange(util.range) AS IMPLICIT;
4967

    
4968

    
4969
SET search_path = util, pg_catalog;
4970

    
4971
--
4972
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4973
--
4974

    
4975
CREATE TABLE map (
4976
    "from" text NOT NULL,
4977
    "to" text,
4978
    filter text,
4979
    notes text
4980
);
4981

    
4982

    
4983
--
4984
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4985
--
4986

    
4987

    
4988

    
4989
--
4990
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4991
--
4992

    
4993

    
4994

    
4995
--
4996
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4997
--
4998

    
4999
ALTER TABLE ONLY map
5000
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
5001

    
5002

    
5003
--
5004
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
5005
--
5006

    
5007
ALTER TABLE ONLY map
5008
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
5009

    
5010

    
5011
--
5012
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
5013
--
5014

    
5015
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
5016

    
5017

    
5018
--
5019
-- PostgreSQL database dump complete
5020
--
5021

    
(21-21/31)