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_num(col_ref); Type: FUNCTION; Schema: util; Owner: -
1043
--
1044

    
1045
CREATE FUNCTION col_num(col col_ref) RETURNS smallint
1046
    LANGUAGE sql STABLE
1047
    AS $_$
1048
SELECT attnum FROM pg_attribute WHERE attrelid = $1.table_ AND attname = $1.name
1049
$_$;
1050

    
1051

    
1052
--
1053
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
1054
--
1055

    
1056
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
1057
    LANGUAGE plpgsql STABLE STRICT
1058
    AS $$
1059
DECLARE
1060
    type regtype;
1061
BEGIN
1062
    SELECT atttypid FROM pg_attribute
1063
    WHERE attrelid = col.table_ AND attname = col.name
1064
    INTO STRICT type
1065
    ;
1066
    RETURN type;
1067
EXCEPTION
1068
    WHEN no_data_found THEN
1069
        RAISE undefined_column USING MESSAGE =
1070
            concat('undefined column: ', col.name);
1071
END;
1072
$$;
1073

    
1074

    
1075
--
1076
-- Name: comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
1077
--
1078

    
1079
CREATE FUNCTION comment(col col_ref) RETURNS text
1080
    LANGUAGE sql STABLE
1081
    AS $_$
1082
SELECT description
1083
FROM pg_description
1084
WHERE
1085
	objoid = $1.table_
1086
AND classoid = 'pg_class'::regclass
1087
AND objsubid = util.col_num($1)
1088
$_$;
1089

    
1090

    
1091
--
1092
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
1093
--
1094

    
1095
CREATE FUNCTION comment(element oid) RETURNS text
1096
    LANGUAGE sql STABLE
1097
    AS $_$
1098
SELECT description FROM pg_description WHERE objoid = $1
1099
$_$;
1100

    
1101

    
1102
--
1103
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
1104
--
1105

    
1106
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
1107
    LANGUAGE sql IMMUTABLE
1108
    AS $_$
1109
SELECT util.esc_name__append($2, $1)
1110
$_$;
1111

    
1112

    
1113
--
1114
-- Name: contained_within__no_dateline(postgis.geometry, postgis.geometry); Type: FUNCTION; Schema: util; Owner: -
1115
--
1116

    
1117
CREATE FUNCTION contained_within__no_dateline("inner" postgis.geometry, "outer" postgis.geometry) RETURNS boolean
1118
    LANGUAGE sql IMMUTABLE
1119
    SET search_path TO postgis
1120
    AS $_$
1121
/* search_path: st_coveredby() needs postgis to be in the search_path */
1122
/* must be st_coveredby() rather than st_within() to avoid unexpected behavior
1123
at the shape border */
1124
SELECT postgis.st_coveredby($1, $2)
1125
$_$;
1126

    
1127

    
1128
--
1129
-- Name: FUNCTION contained_within__no_dateline("inner" postgis.geometry, "outer" postgis.geometry); Type: COMMENT; Schema: util; Owner: -
1130
--
1131

    
1132
COMMENT ON FUNCTION contained_within__no_dateline("inner" postgis.geometry, "outer" postgis.geometry) IS '
1133
**WARNING**: this will not work on shapes that cross the date line, as the
1134
geometry type does not support geocoordinate wraparound
1135
';
1136

    
1137

    
1138
--
1139
-- Name: contained_within__no_dateline(geocoord, postgis.geometry); Type: FUNCTION; Schema: util; Owner: -
1140
--
1141

    
1142
CREATE FUNCTION contained_within__no_dateline(point geocoord, region postgis.geometry) RETURNS boolean
1143
    LANGUAGE sql IMMUTABLE
1144
    AS $_$
1145
SELECT util.contained_within__no_dateline(util.geometry($1), $2)
1146
$_$;
1147

    
1148

    
1149
--
1150
-- Name: FUNCTION contained_within__no_dateline(point geocoord, region postgis.geometry); Type: COMMENT; Schema: util; Owner: -
1151
--
1152

    
1153
COMMENT ON FUNCTION contained_within__no_dateline(point geocoord, region postgis.geometry) IS '
1154
defining this in addition to contained_within_approx(geometry, geometry) enables
1155
specifying just `(lat, long)` without the ::util.geocoord type specifier
1156
';
1157

    
1158

    
1159
--
1160
-- Name: contained_within_approx(postgis.geography, postgis.geography); Type: FUNCTION; Schema: util; Owner: -
1161
--
1162

    
1163
CREATE FUNCTION contained_within_approx("inner" postgis.geography, "outer" postgis.geography) RETURNS boolean
1164
    LANGUAGE sql IMMUTABLE
1165
    SET search_path TO postgis
1166
    AS $_$
1167
/* search_path: st_coveredby() needs postgis to be in the search_path */
1168
SELECT postgis.st_coveredby($1, $2)
1169
$_$;
1170

    
1171

    
1172
--
1173
-- Name: FUNCTION contained_within_approx("inner" postgis.geography, "outer" postgis.geography); Type: COMMENT; Schema: util; Owner: -
1174
--
1175

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

    
1182

    
1183
--
1184
-- Name: contained_within_approx(geocoord, postgis.geography); Type: FUNCTION; Schema: util; Owner: -
1185
--
1186

    
1187
CREATE FUNCTION contained_within_approx(point geocoord, region postgis.geography) RETURNS boolean
1188
    LANGUAGE sql IMMUTABLE
1189
    AS $_$
1190
SELECT util.contained_within_approx(util.geometry($1), $2)
1191
$_$;
1192

    
1193

    
1194
--
1195
-- Name: FUNCTION contained_within_approx(point geocoord, region postgis.geography); Type: COMMENT; Schema: util; Owner: -
1196
--
1197

    
1198
COMMENT ON FUNCTION contained_within_approx(point geocoord, region postgis.geography) IS '
1199
defining this in addition to contained_within_approx(geography, geography)
1200
enables specifying just `(lat, long)` without the ::util.geocoord type specifier
1201
';
1202

    
1203

    
1204
--
1205
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
1206
--
1207

    
1208
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
1209
    LANGUAGE sql IMMUTABLE
1210
    AS $_$
1211
SELECT position($1 in $2) > 0 /*1-based offset*/
1212
$_$;
1213

    
1214

    
1215
--
1216
-- Name: copy(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1217
--
1218

    
1219
CREATE FUNCTION copy(from_ regclass, to_ text) RETURNS void
1220
    LANGUAGE sql
1221
    AS $_$
1222
SELECT util.copy_struct($1, $2);
1223
SELECT util.copy_data($1, $2);
1224
$_$;
1225

    
1226

    
1227
--
1228
-- Name: copy_data(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1229
--
1230

    
1231
CREATE FUNCTION copy_data(from_ regclass, to_ regclass) RETURNS void
1232
    LANGUAGE sql
1233
    AS $_$
1234
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT * FROM $$||$1)
1235
$_$;
1236

    
1237

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

    
1242
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1243
    LANGUAGE sql
1244
    AS $_$
1245
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1246
$_$;
1247

    
1248

    
1249
--
1250
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1251
--
1252

    
1253
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1254
    LANGUAGE sql
1255
    AS $_$
1256
SELECT util.materialize_view($2, $1)
1257
$_$;
1258

    
1259

    
1260
--
1261
-- Name: create_if_not_exists(text, text); Type: FUNCTION; Schema: util; Owner: -
1262
--
1263

    
1264
CREATE FUNCTION create_if_not_exists(sql text, relation text DEFAULT NULL::text) RETURNS void
1265
    LANGUAGE plpgsql
1266
    AS $$
1267
BEGIN
1268
	/* always generate standard exception if exists, even if table definition
1269
	would be invalid (which generates a variety of exceptions) */
1270
	IF util.relation_exists(relation) THEN
1271
		PERFORM util.raise('NOTICE', relation||' already exists, skipping');
1272
		RAISE duplicate_table;
1273
	END IF;
1274
	PERFORM util.eval(sql);
1275
EXCEPTION
1276
WHEN   duplicate_table
1277
	OR duplicate_object -- eg. constraint
1278
	OR duplicate_column
1279
	OR duplicate_function
1280
THEN NULL;
1281
WHEN invalid_table_definition THEN
1282
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1283
	ELSE RAISE;
1284
	END IF;
1285
END;
1286
$$;
1287

    
1288

    
1289
--
1290
-- Name: FUNCTION create_if_not_exists(sql text, relation text); Type: COMMENT; Schema: util; Owner: -
1291
--
1292

    
1293
COMMENT ON FUNCTION create_if_not_exists(sql text, relation text) IS '
1294
idempotent
1295
';
1296

    
1297

    
1298
--
1299
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1300
--
1301

    
1302
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1303
    LANGUAGE sql STABLE
1304
    AS $$
1305
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1306
$$;
1307

    
1308

    
1309
--
1310
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1311
--
1312

    
1313
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1314
    LANGUAGE sql IMMUTABLE
1315
    AS $_$
1316
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1317
$_$;
1318

    
1319

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

    
1324
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1325
    LANGUAGE sql IMMUTABLE
1326
    AS $_$
1327
SELECT util.debug_print_value('returns: ', $1, $2);
1328
SELECT $1;
1329
$_$;
1330

    
1331

    
1332
--
1333
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1334
--
1335

    
1336
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1337
    LANGUAGE sql IMMUTABLE
1338
    AS $_$
1339
/* newline before so the query starts at the beginning of the line.
1340
newline after to visually separate queries from one another. */
1341
SELECT util.raise('NOTICE', $$
1342
$$||util.runnable_sql($1)||$$
1343
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1344
$_$;
1345

    
1346

    
1347
--
1348
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1349
--
1350

    
1351
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1352
    LANGUAGE sql IMMUTABLE
1353
    AS $_$
1354
SELECT util.raise('NOTICE', concat($1,
1355
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1356
$$)
1357
$_$;
1358

    
1359

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

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

    
1373

    
1374
--
1375
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1376
--
1377

    
1378
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1379
    LANGUAGE sql STABLE
1380
    AS $_$
1381
SELECT util.eval2set($$
1382
SELECT col
1383
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1384
LEFT JOIN $$||$2||$$ ON "to" = col
1385
WHERE "from" IS NULL
1386
$$, NULL::text)
1387
$_$;
1388

    
1389

    
1390
--
1391
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1392
--
1393

    
1394
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1395
gets table_''s derived columns (all the columns not in the names table)
1396
';
1397

    
1398

    
1399
--
1400
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1401
--
1402

    
1403
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1404
    LANGUAGE sql
1405
    AS $_$
1406
-- create a diff when the # of copies of a row differs between the tables
1407
SELECT util.to_freq($1);
1408
SELECT util.to_freq($2);
1409
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1410

    
1411
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1412
$_$;
1413

    
1414

    
1415
--
1416
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1417
--
1418

    
1419
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1420
usage:
1421
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1422

    
1423
col_type_null (*required*): NULL::shared_base_type
1424
';
1425

    
1426

    
1427
--
1428
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1429
--
1430

    
1431
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
1432
    LANGUAGE plpgsql
1433
    SET search_path TO pg_temp
1434
    AS $_$
1435
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1436
changes of search_path (schema elements are bound at inline time rather than
1437
runtime) */
1438
/* function option search_path is needed to limit the effects of
1439
`SET LOCAL search_path` to the current function */
1440
BEGIN
1441
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1442
	
1443
	PERFORM util.mk_keys_func(pg_typeof($3));
1444
	RETURN QUERY
1445
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1446
$$/* need to explicitly cast each side to the return type because this does not
1447
happen automatically even when an implicit cast is available */
1448
  left_::$$||util.typeof($3)||$$
1449
, right_::$$||util.typeof($3)
1450
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1451
the *same* base type, *even though* this is optional when using a custom %== */
1452
, util._if($4, $$true/*= CROSS JOIN*/$$,
1453
$$ left_::$$||util.typeof($3)||$$
1454
%== right_::$$||util.typeof($3)||$$
1455
	-- refer to EXPLAIN output for expansion of %==$$
1456
)
1457
,     $$         left_::$$||util.typeof($3)||$$
1458
IS DISTINCT FROM right_::$$||util.typeof($3)
1459
), $3)
1460
	;
1461
END;
1462
$_$;
1463

    
1464

    
1465
--
1466
-- 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: -
1467
--
1468

    
1469
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1470
col_type_null (*required*): NULL::col_type
1471
single_row: whether the tables consist of a single row, which should be
1472
	displayed side-by-side
1473

    
1474
to match up rows using a subset of the columns, create a custom keys() function
1475
which returns this subset as a record:
1476
-- note that OUT parameters for the returned fields are *not* needed
1477
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1478
  RETURNS record AS
1479
$BODY$
1480
SELECT ($1.key_field_0, $1.key_field_1)
1481
$BODY$
1482
  LANGUAGE sql IMMUTABLE
1483
  COST 100;
1484

    
1485

    
1486
to run EXPLAIN on the FULL JOIN query:
1487
# run this function
1488
# look for a NOTICE containing the expanded query that it ran
1489
# run EXPLAIN on this expanded query
1490
';
1491

    
1492

    
1493
--
1494
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1495
--
1496

    
1497
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
1498
    LANGUAGE sql
1499
    AS $_$
1500
SELECT * FROM util.diff($1::text, $2::text, $3,
1501
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1502
$_$;
1503

    
1504

    
1505
--
1506
-- 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: -
1507
--
1508

    
1509
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1510
helper function used by diff(regclass, regclass)
1511

    
1512
usage:
1513
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1514

    
1515
col_type_null (*required*): NULL::shared_base_type
1516
';
1517

    
1518

    
1519
--
1520
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1521
--
1522

    
1523
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1524
    LANGUAGE sql
1525
    AS $_$
1526
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1527
$_$;
1528

    
1529

    
1530
--
1531
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1532
--
1533

    
1534
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1535
idempotent
1536
';
1537

    
1538

    
1539
--
1540
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1541
--
1542

    
1543
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1544
    LANGUAGE sql
1545
    AS $_$
1546
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1547
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1548
$_$;
1549

    
1550

    
1551
--
1552
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1553
--
1554

    
1555
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1556
idempotent
1557
';
1558

    
1559

    
1560
--
1561
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1562
--
1563

    
1564
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1565
    LANGUAGE sql
1566
    AS $_$
1567
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1568
SELECT NULL::void; -- don't fold away functions called in previous query
1569
$_$;
1570

    
1571

    
1572
--
1573
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1574
--
1575

    
1576
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1577
idempotent
1578
';
1579

    
1580

    
1581
--
1582
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1583
--
1584

    
1585
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1586
    LANGUAGE sql
1587
    AS $_$
1588
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1589
included in the debug SQL */
1590
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1591
$_$;
1592

    
1593

    
1594
--
1595
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1596
--
1597

    
1598
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1599
    LANGUAGE sql
1600
    AS $_$
1601
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1602
||util._if($3, $$ CASCADE$$, ''::text))
1603
$_$;
1604

    
1605

    
1606
--
1607
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1608
--
1609

    
1610
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1611
idempotent
1612
';
1613

    
1614

    
1615
--
1616
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1617
--
1618

    
1619
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1620
    LANGUAGE sql
1621
    AS $_$
1622
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1623
$_$;
1624

    
1625

    
1626
--
1627
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1628
--
1629

    
1630
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1631
    LANGUAGE sql
1632
    AS $_$
1633
SELECT util.debug_print_func_call(util.quote_func_call(
1634
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1635
util.quote_typed($3)))
1636
;
1637
SELECT util.drop_relation(relation, $3)
1638
FROM util.show_relations_like($1, $2) relation
1639
;
1640
SELECT NULL::void; -- don't fold away functions called in previous query
1641
$_$;
1642

    
1643

    
1644
--
1645
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1646
--
1647

    
1648
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1649
    LANGUAGE sql
1650
    AS $_$
1651
SELECT util.drop_relation('TABLE', $1, $2)
1652
$_$;
1653

    
1654

    
1655
--
1656
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1657
--
1658

    
1659
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1660
idempotent
1661
';
1662

    
1663

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

    
1668
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1669
    LANGUAGE sql
1670
    AS $_$
1671
SELECT util.drop_relation('VIEW', $1, $2)
1672
$_$;
1673

    
1674

    
1675
--
1676
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1677
--
1678

    
1679
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1680
idempotent
1681
';
1682

    
1683

    
1684
--
1685
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1686
--
1687

    
1688
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1689
    LANGUAGE sql IMMUTABLE
1690
    AS $_$
1691
SELECT util.array_fill($1, 0)
1692
$_$;
1693

    
1694

    
1695
--
1696
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1697
--
1698

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

    
1703

    
1704
--
1705
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1706
--
1707

    
1708
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1709
    LANGUAGE sql IMMUTABLE
1710
    AS $_$
1711
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1712
$_$;
1713

    
1714

    
1715
--
1716
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1717
--
1718

    
1719
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1720
    LANGUAGE sql IMMUTABLE
1721
    AS $_$
1722
SELECT regexp_replace($2, '("?)$', $1||'\1')
1723
$_$;
1724

    
1725

    
1726
--
1727
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1728
--
1729

    
1730
CREATE FUNCTION eval(queries text[]) RETURNS void
1731
    LANGUAGE sql
1732
    AS $_$
1733
SELECT util.eval(query) FROM unnest($1) query;
1734
SELECT NULL::void; -- don't fold away functions called in previous query
1735
$_$;
1736

    
1737

    
1738
--
1739
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1740
--
1741

    
1742
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1743
    LANGUAGE plpgsql
1744
    AS $$
1745
BEGIN
1746
	sql = util.view_def_to_orig(sql); -- restore user's intent
1747
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1748
	EXECUTE sql;
1749
END;
1750
$$;
1751

    
1752

    
1753
--
1754
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1755
--
1756

    
1757
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1758
    LANGUAGE plpgsql
1759
    AS $$
1760
BEGIN
1761
	PERFORM util.debug_print_sql(sql);
1762
	RETURN QUERY EXECUTE sql;
1763
END;
1764
$$;
1765

    
1766

    
1767
--
1768
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1769
--
1770

    
1771
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1772
col_type_null (*required*): NULL::col_type
1773
';
1774

    
1775

    
1776
--
1777
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1778
--
1779

    
1780
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1781
    LANGUAGE plpgsql
1782
    AS $$
1783
BEGIN
1784
	PERFORM util.debug_print_sql(sql);
1785
	RETURN QUERY EXECUTE sql;
1786
END;
1787
$$;
1788

    
1789

    
1790
--
1791
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1792
--
1793

    
1794
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1795
    LANGUAGE plpgsql
1796
    AS $$
1797
BEGIN
1798
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1799
	RETURN QUERY EXECUTE sql;
1800
END;
1801
$$;
1802

    
1803

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

    
1808
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1809
    LANGUAGE plpgsql STABLE
1810
    AS $$
1811
DECLARE
1812
	ret_val ret_type_null%TYPE;
1813
BEGIN
1814
	PERFORM util.debug_print_sql(sql);
1815
	EXECUTE sql INTO STRICT ret_val;
1816
	RETURN ret_val;
1817
END;
1818
$$;
1819

    
1820

    
1821
--
1822
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1823
--
1824

    
1825
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1826
ret_type_null: NULL::ret_type
1827
';
1828

    
1829

    
1830
--
1831
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1832
--
1833

    
1834
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1835
    LANGUAGE sql
1836
    AS $_$
1837
SELECT util.eval2val($$SELECT $$||$1, $2)
1838
$_$;
1839

    
1840

    
1841
--
1842
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1843
--
1844

    
1845
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1846
ret_type_null: NULL::ret_type
1847
';
1848

    
1849

    
1850
--
1851
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1852
--
1853

    
1854
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1855
    LANGUAGE sql
1856
    AS $_$
1857
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1858
$_$;
1859

    
1860

    
1861
--
1862
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1863
--
1864

    
1865
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1866
sql: can be NULL, which will be passed through
1867
ret_type_null: NULL::ret_type
1868
';
1869

    
1870

    
1871
--
1872
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1873
--
1874

    
1875
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1876
    LANGUAGE sql STABLE
1877
    AS $_$
1878
SELECT col_name
1879
FROM unnest($2) s (col_name)
1880
WHERE util.col_exists(($1, col_name))
1881
$_$;
1882

    
1883

    
1884
--
1885
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1886
--
1887

    
1888
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1889
    LANGUAGE sql
1890
    SET client_min_messages TO 'error'
1891
    AS $_$
1892
/* `client_min_messages = ERROR`: EXPLAIN apparently runs IMMUTABLE functions in
1893
the query, so this prevents displaying any log messages printed by them */
1894
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1895
$_$;
1896

    
1897

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

    
1902
CREATE FUNCTION explain2notice(sql text) RETURNS void
1903
    LANGUAGE sql
1904
    AS $_$
1905
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1906
$_$;
1907

    
1908

    
1909
--
1910
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1911
--
1912

    
1913
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1914
    LANGUAGE sql
1915
    AS $_$
1916
-- newline before and after to visually separate it from other debug info
1917
SELECT COALESCE($$
1918
EXPLAIN:
1919
$$||util.fold_explain_msg(util.explain2str($1))||$$
1920
$$, '')
1921
$_$;
1922

    
1923

    
1924
--
1925
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1926
--
1927

    
1928
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1929
    LANGUAGE plpgsql
1930
    AS $$
1931
BEGIN
1932
	RETURN util.explain2notice_msg(sql);
1933
EXCEPTION
1934
WHEN   syntax_error
1935
	OR invalid_cursor_definition -- "cannot open multi-query plan as cursor"
1936
	THEN RETURN NULL; -- non-explainable query
1937
	/* don't use util.is_explainable() because the list provided by Postgres
1938
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1939
	excludes some query types that are in fact EXPLAIN-able */
1940
END;
1941
$$;
1942

    
1943

    
1944
--
1945
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1946
--
1947

    
1948
CREATE FUNCTION explain2str(sql text) RETURNS text
1949
    LANGUAGE sql
1950
    AS $_$
1951
SELECT util.join_strs(explain, $$
1952
$$) FROM util.explain($1)
1953
$_$;
1954

    
1955

    
1956
SET default_tablespace = '';
1957

    
1958
SET default_with_oids = false;
1959

    
1960
--
1961
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1962
--
1963

    
1964
CREATE TABLE explain (
1965
    line text NOT NULL
1966
);
1967

    
1968

    
1969
--
1970
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1971
--
1972

    
1973
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1974
    LANGUAGE sql
1975
    AS $_$
1976
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1977
$$||quote_nullable($1)||$$
1978
)$$)
1979
$_$;
1980

    
1981

    
1982
--
1983
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1984
--
1985

    
1986
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1987
usage:
1988
PERFORM util.explain2table($$
1989
query
1990
$$);
1991
';
1992

    
1993

    
1994
--
1995
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1996
--
1997

    
1998
CREATE FUNCTION first_word(str text) RETURNS text
1999
    LANGUAGE sql IMMUTABLE
2000
    AS $_$
2001
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
2002
$_$;
2003

    
2004

    
2005
--
2006
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
2007
--
2008

    
2009
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
2010
    LANGUAGE sql IMMUTABLE
2011
    AS $_$
2012
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
2013
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
2014
) END
2015
$_$;
2016

    
2017

    
2018
--
2019
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
2020
--
2021

    
2022
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
2023
ensures that an array will always have proper non-NULL dimensions
2024
';
2025

    
2026

    
2027
--
2028
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
2029
--
2030

    
2031
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
2032
    LANGUAGE sql IMMUTABLE
2033
    AS $_$
2034
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
2035
$_$;
2036

    
2037

    
2038
--
2039
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
2040
--
2041

    
2042
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
2043
    LANGUAGE plpgsql STRICT
2044
    AS $_$
2045
DECLARE
2046
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
2047
$$||query;
2048
BEGIN
2049
	EXECUTE mk_view;
2050
EXCEPTION
2051
WHEN invalid_table_definition THEN
2052
	IF SQLERRM = 'cannot drop columns from view'
2053
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
2054
	THEN
2055
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
2056
		EXECUTE mk_view;
2057
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
2058
	END IF;
2059
END;
2060
$_$;
2061

    
2062

    
2063
--
2064
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
2065
--
2066

    
2067
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
2068
idempotent
2069
';
2070

    
2071

    
2072
--
2073
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2074
--
2075

    
2076
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
2077
    LANGUAGE sql STABLE
2078
    AS $_$
2079
SELECT util.eval2val(
2080
$$SELECT NOT EXISTS( -- there is no row that is != 1
2081
	SELECT NULL
2082
	FROM $$||$1||$$
2083
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
2084
	LIMIT 1
2085
)
2086
$$, NULL::boolean)
2087
$_$;
2088

    
2089

    
2090
--
2091
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
2092
--
2093

    
2094
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
2095
    LANGUAGE sql STABLE
2096
    AS $_$
2097
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
2098
$_$;
2099

    
2100

    
2101
--
2102
-- Name: geometry(geocoord); Type: FUNCTION; Schema: util; Owner: -
2103
--
2104

    
2105
CREATE FUNCTION geometry(geocoord geocoord) RETURNS postgis.geometry
2106
    LANGUAGE sql IMMUTABLE
2107
    SET client_min_messages TO 'warning'
2108
    AS $_$
2109
SELECT postgis.st_setsrid(postgis.st_point(
2110
/*x_lon=*/$1.longitude_deg, /*y_lat=*/$1.latitude_deg),
2111
/*WGS84*/4326)
2112
$_$;
2113

    
2114

    
2115
--
2116
-- Name: FUNCTION geometry(geocoord geocoord); Type: COMMENT; Schema: util; Owner: -
2117
--
2118

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

    
2124

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

    
2129
CREATE FUNCTION grants_users() RETURNS SETOF text
2130
    LANGUAGE sql IMMUTABLE
2131
    AS $$
2132
VALUES ('bien_read'), ('public_')
2133
$$;
2134

    
2135

    
2136
--
2137
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
2138
--
2139

    
2140
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
2141
    LANGUAGE sql IMMUTABLE
2142
    AS $_$
2143
SELECT substring($2 for length($1)) = $1
2144
$_$;
2145

    
2146

    
2147
--
2148
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
2149
--
2150

    
2151
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
2152
    LANGUAGE sql STABLE
2153
    AS $_$
2154
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
2155
$_$;
2156

    
2157

    
2158
--
2159
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
2160
--
2161

    
2162
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
2163
    LANGUAGE sql IMMUTABLE
2164
    AS $_$
2165
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
2166
$_$;
2167

    
2168

    
2169
--
2170
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
2171
--
2172

    
2173
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
2174
avoids repeating the same value for each key
2175
';
2176

    
2177

    
2178
--
2179
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2180
--
2181

    
2182
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
2183
    LANGUAGE sql IMMUTABLE
2184
    AS $_$
2185
SELECT COALESCE($1, $2)
2186
$_$;
2187

    
2188

    
2189
--
2190
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
2191
--
2192

    
2193
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
2194
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
2195
';
2196

    
2197

    
2198
--
2199
-- Name: in_new_world(geocoord); Type: FUNCTION; Schema: util; Owner: -
2200
--
2201

    
2202
CREATE FUNCTION in_new_world(point geocoord) RETURNS boolean
2203
    LANGUAGE sql IMMUTABLE
2204
    AS $_$
2205
/* use function rather than operator+search_path to allow inlining, which
2206
enables util.new_world() to only be evaluated once */
2207
SELECT util.contained_within_approx($1, util.new_world())
2208
$_$;
2209

    
2210

    
2211
--
2212
-- Name: FUNCTION in_new_world(point geocoord); Type: COMMENT; Schema: util; Owner: -
2213
--
2214

    
2215
COMMENT ON FUNCTION in_new_world(point geocoord) IS '
2216
**WARNING**: this includes false positives above and below the New World
2217
bounding box, as described in util.bounding_box()
2218
';
2219

    
2220

    
2221
--
2222
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
2223
--
2224

    
2225
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
2226
    LANGUAGE sql IMMUTABLE
2227
    AS $_$
2228
SELECT elem FROM unnest($1) elem ORDER BY row_number() OVER () DESC
2229
$_$;
2230

    
2231

    
2232
--
2233
-- Name: in_south_america(geocoord); Type: FUNCTION; Schema: util; Owner: -
2234
--
2235

    
2236
CREATE FUNCTION in_south_america(point geocoord) RETURNS boolean
2237
    LANGUAGE sql IMMUTABLE
2238
    AS $_$
2239
/* use function rather than operator+search_path to allow inlining, which
2240
enables util.south_america() to only be evaluated once */
2241
SELECT $1.latitude_deg BETWEEN -56 AND 13 AND $1.longitude_deg BETWEEN -82 AND -34
2242
$_$;
2243

    
2244

    
2245
--
2246
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2247
--
2248

    
2249
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
2250
    LANGUAGE sql
2251
    AS $_$
2252
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
2253
$_$;
2254

    
2255

    
2256
--
2257
-- Name: is_castable(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2258
--
2259

    
2260
CREATE FUNCTION is_castable(value text, ret_type_null anyelement) RETURNS boolean
2261
    LANGUAGE plpgsql IMMUTABLE
2262
    AS $$
2263
BEGIN
2264
	PERFORM util.cast(value, ret_type_null);
2265
	-- must happen *after* cast check, because NULL is not valid for some types
2266
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
2267
	RETURN true;
2268
EXCEPTION
2269
WHEN   data_exception
2270
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
2271
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
2272
	THEN
2273
	RETURN false;
2274
END;
2275
$$;
2276

    
2277

    
2278
--
2279
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
2280
--
2281

    
2282
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
2283
passes NULL through. however, if NULL is not valid for the type, false will be
2284
returned instead.
2285

    
2286
ret_type_null: NULL::ret_type
2287
';
2288

    
2289

    
2290
--
2291
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
2292
--
2293

    
2294
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
2295
    LANGUAGE sql STABLE
2296
    AS $_$
2297
SELECT COALESCE(util.col_comment($1) LIKE '
2298
constant
2299
%', false)
2300
$_$;
2301

    
2302

    
2303
--
2304
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2305
--
2306

    
2307
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
2308
    LANGUAGE sql IMMUTABLE
2309
    AS $_$
2310
SELECT util.array_length($1) = 0
2311
$_$;
2312

    
2313

    
2314
--
2315
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
2316
--
2317

    
2318
CREATE FUNCTION is_explain(sql text) RETURNS boolean
2319
    LANGUAGE sql IMMUTABLE
2320
    AS $_$
2321
SELECT upper(util.first_word($1)) = 'EXPLAIN'
2322
$_$;
2323

    
2324

    
2325
--
2326
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
2327
--
2328

    
2329
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
2330
    LANGUAGE sql IMMUTABLE
2331
    AS $_$
2332
SELECT upper(util.first_word($1)) = ANY(
2333
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
2334
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
2335
)
2336
$_$;
2337

    
2338

    
2339
--
2340
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2341
--
2342

    
2343
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
2344
    LANGUAGE sql IMMUTABLE
2345
    AS $_$
2346
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2347
$_$;
2348

    
2349

    
2350
--
2351
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2352
--
2353

    
2354
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2355
    LANGUAGE sql IMMUTABLE
2356
    AS $_$
2357
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2358
$_$;
2359

    
2360

    
2361
--
2362
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
2363
--
2364

    
2365
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2366
    LANGUAGE sql IMMUTABLE
2367
    AS $_$
2368
SELECT upper(util.first_word($1)) = 'SET'
2369
$_$;
2370

    
2371

    
2372
--
2373
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
2374
--
2375

    
2376
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2377
    LANGUAGE sql STABLE
2378
    AS $_$
2379
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2380
$_$;
2381

    
2382

    
2383
--
2384
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2385
--
2386

    
2387
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2388
    LANGUAGE sql STABLE
2389
    AS $_$
2390
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2391
$_$;
2392

    
2393

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

    
2398
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2399
    LANGUAGE sql IMMUTABLE STRICT
2400
    AS $_$
2401
SELECT $1 || $3 || $2
2402
$_$;
2403

    
2404

    
2405
--
2406
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2407
--
2408

    
2409
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2410
must be declared STRICT to use the special handling of STRICT aggregating functions
2411
';
2412

    
2413

    
2414
--
2415
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2416
--
2417

    
2418
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2419
    LANGUAGE sql IMMUTABLE
2420
    AS $_$
2421
SELECT $1 -- compare on the entire value
2422
$_$;
2423

    
2424

    
2425
--
2426
-- Name: keys_eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2427
--
2428

    
2429
CREATE FUNCTION keys_eq(left_ anyelement, right_ anyelement) RETURNS boolean
2430
    LANGUAGE sql STABLE
2431
    AS $_$
2432
SELECT keys($1) = keys($2)
2433
$_$;
2434

    
2435

    
2436
--
2437
-- Name: FUNCTION keys_eq(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
2438
--
2439

    
2440
COMMENT ON FUNCTION keys_eq(left_ anyelement, right_ anyelement) IS '
2441
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**)
2442
';
2443

    
2444

    
2445
--
2446
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2447
--
2448

    
2449
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2450
    LANGUAGE sql IMMUTABLE
2451
    AS $_$
2452
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2453
$_$;
2454

    
2455

    
2456
--
2457
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2458
--
2459

    
2460
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2461
    LANGUAGE plpgsql
2462
    AS $$
2463
DECLARE
2464
	errors_ct integer = 0;
2465
	loop_var loop_type_null%TYPE;
2466
BEGIN
2467
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2468
	LOOP
2469
		BEGIN
2470
			EXECUTE loop_body_sql USING loop_var;
2471
		EXCEPTION
2472
		WHEN OTHERS THEN
2473
			errors_ct = errors_ct+1;
2474
			PERFORM util.raise_error_warning(SQLERRM);
2475
		END;
2476
	END LOOP;
2477
	IF errors_ct > 0 THEN
2478
		-- can't raise exception because this would roll back the transaction
2479
		PERFORM util.raise_error_warning('there were '||errors_ct
2480
			||' errors: see the WARNINGs for details');
2481
	END IF;
2482
END;
2483
$$;
2484

    
2485

    
2486
--
2487
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2488
--
2489

    
2490
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2491
    LANGUAGE sql IMMUTABLE
2492
    AS $_$
2493
SELECT ltrim($1, $$
2494
$$)
2495
$_$;
2496

    
2497

    
2498
--
2499
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2500
--
2501

    
2502
CREATE FUNCTION map_filter_insert() RETURNS trigger
2503
    LANGUAGE plpgsql
2504
    AS $$
2505
BEGIN
2506
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2507
	RETURN new;
2508
END;
2509
$$;
2510

    
2511

    
2512
--
2513
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2514
--
2515

    
2516
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2517
    LANGUAGE plpgsql STABLE STRICT
2518
    AS $_$
2519
DECLARE
2520
    value text;
2521
BEGIN
2522
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2523
        INTO value USING key;
2524
    RETURN value;
2525
END;
2526
$_$;
2527

    
2528

    
2529
--
2530
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2531
--
2532

    
2533
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2534
    LANGUAGE sql IMMUTABLE
2535
    AS $_$
2536
SELECT util._map(util.nulls_map($1), $2)
2537
$_$;
2538

    
2539

    
2540
--
2541
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2542
--
2543

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

    
2547
[1] inlining of function calls, which is different from constant folding
2548
[2] _map()''s profiling query
2549
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2550
and map_nulls()''s profiling query
2551
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2552
both take ~920 ms.
2553
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.
2554
';
2555

    
2556

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

    
2561
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2562
    LANGUAGE plpgsql STABLE STRICT
2563
    AS $_$
2564
BEGIN
2565
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2566
END;
2567
$_$;
2568

    
2569

    
2570
--
2571
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2572
--
2573

    
2574
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2575
    LANGUAGE sql
2576
    AS $_$
2577
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2578
$$||util.ltrim_nl($2));
2579
-- make sure the created table has the correct estimated row count
2580
SELECT util.analyze_($1);
2581

    
2582
SELECT util.append_comment($1, '
2583
contents generated from:
2584
'||util.ltrim_nl(util.runnable_sql($2))||';
2585
');
2586
$_$;
2587

    
2588

    
2589
--
2590
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2591
--
2592

    
2593
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2594
idempotent
2595
';
2596

    
2597

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

    
2602
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2603
    LANGUAGE sql
2604
    AS $_$
2605
SELECT util.create_if_not_exists($$
2606
SELECT util.copy($$||util.quote_typed($2)||$$, $$||util.quote_typed($1)||$$)
2607
$$);
2608
$_$;
2609

    
2610

    
2611
--
2612
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2613
--
2614

    
2615
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2616
idempotent
2617
';
2618

    
2619

    
2620
--
2621
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2622
--
2623

    
2624
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2625
    LANGUAGE sql
2626
    AS $_$
2627
SELECT util.create_if_not_exists($$
2628
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2629
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2630
||quote_literal($2)||$$;
2631
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2632
constant
2633
';
2634
$$)
2635
$_$;
2636

    
2637

    
2638
--
2639
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2640
--
2641

    
2642
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2643
idempotent
2644
';
2645

    
2646

    
2647
--
2648
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2649
--
2650

    
2651
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2652
    LANGUAGE plpgsql STRICT
2653
    AS $_$
2654
DECLARE
2655
    type regtype = util.typeof(expr, col.table_::text::regtype);
2656
    col_name_sql text = quote_ident(col.name);
2657
BEGIN
2658
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2659
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2660
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2661
$$||expr||$$;
2662
$$);
2663
END;
2664
$_$;
2665

    
2666

    
2667
--
2668
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2669
--
2670

    
2671
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2672
idempotent
2673
';
2674

    
2675

    
2676
--
2677
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2678
--
2679

    
2680
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
2681
    LANGUAGE sql IMMUTABLE
2682
    AS $_$
2683
SELECT
2684
$$SELECT
2685
$$||$3||$$
2686
FROM      $$||$1||$$ left_
2687
FULL JOIN $$||$2||$$ right_
2688
ON $$||$4||$$
2689
WHERE $$||$5||$$
2690
ORDER BY left_, right_
2691
$$
2692
$_$;
2693

    
2694

    
2695
--
2696
-- Name: mk_drop_from_create(text); Type: FUNCTION; Schema: util; Owner: -
2697
--
2698

    
2699
CREATE FUNCTION mk_drop_from_create(create_cmd text) RETURNS text
2700
    LANGUAGE sql IMMUTABLE
2701
    AS $_$
2702
SELECT $$DROP $$||(util.regexp_match($1,
2703
-- match first CREATE, *if* no DROP came before it
2704
'(?m)\A(?:^(?!DROP\y).*\n)*?^CREATE(?: OR REPLACE)? ((?:)??[[:upper:]]+ .*?)(?: AS(?: (?:SELECT\y.*)?)?)?$'
2705
	/* (?:)?? makes the surrounding () group non-greedy, so that (?: AS ?)?
2706
	works properly (due to nonstandard Postgres regexp behavior:
2707
	http://www.postgresql.org/docs/9.3/static/functions-matching.html#POSIX-MATCHING-RULES) */
2708
))[1]||$$;$$
2709
$_$;
2710

    
2711

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

    
2716
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2717
    LANGUAGE sql
2718
    AS $_$
2719
-- keys()
2720
SELECT util.mk_keys_func($1, ARRAY(
2721
SELECT col FROM util.typed_cols($1) col
2722
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2723
));
2724

    
2725
-- values_()
2726
SELECT util.mk_keys_func($1, COALESCE(
2727
	NULLIF(ARRAY(
2728
	SELECT col FROM util.typed_cols($1) col
2729
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2730
	), ARRAY[]::util.col_cast[])
2731
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2732
, 'values_');
2733
$_$;
2734

    
2735

    
2736
--
2737
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2738
--
2739

    
2740
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2741
    LANGUAGE sql
2742
    AS $_$
2743
SELECT util.create_if_not_exists($$
2744
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2745
($$||util.mk_typed_cols_list($2)||$$);
2746
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2747
autogenerated
2748
';
2749
$$);
2750

    
2751
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2752
$_$;
2753

    
2754

    
2755
--
2756
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2757
--
2758

    
2759
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2760
    LANGUAGE sql
2761
    AS $_$
2762
SELECT util.create_if_not_exists($$
2763
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2764
||util.qual_name($1)||$$)
2765
  RETURNS $$||util.qual_name($2)||$$ AS
2766
$BODY1$
2767
SELECT ROW($$||
2768
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2769
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2770
$BODY1$
2771
  LANGUAGE sql IMMUTABLE
2772
  COST 100;
2773
$$);
2774
$_$;
2775

    
2776

    
2777
--
2778
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2779
--
2780

    
2781
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2782
    LANGUAGE sql
2783
    AS $_$
2784
SELECT util.create_if_not_exists($$
2785
CREATE TABLE $$||$1||$$
2786
(
2787
    LIKE util.map INCLUDING ALL
2788
);
2789

    
2790
CREATE TRIGGER map_filter_insert
2791
  BEFORE INSERT
2792
  ON $$||$1||$$
2793
  FOR EACH ROW
2794
  EXECUTE PROCEDURE util.map_filter_insert();
2795
$$)
2796
$_$;
2797

    
2798

    
2799
--
2800
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2801
--
2802

    
2803
CREATE FUNCTION mk_not_null(text) RETURNS text
2804
    LANGUAGE sql IMMUTABLE
2805
    AS $_$
2806
SELECT COALESCE($1, '<NULL>')
2807
$_$;
2808

    
2809

    
2810
--
2811
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2812
--
2813

    
2814
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2815
    LANGUAGE sql IMMUTABLE
2816
    AS $_$
2817
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2818
util.qual_name((unnest).type), ''), '')
2819
FROM unnest($1)
2820
$_$;
2821

    
2822

    
2823
--
2824
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2825
--
2826

    
2827
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2828
    LANGUAGE sql IMMUTABLE
2829
    AS $_$
2830
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2831
$_$;
2832

    
2833

    
2834
--
2835
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2836
--
2837

    
2838
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2839
auto-appends util to the search_path to enable use of util operators
2840
';
2841

    
2842

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

    
2847
CREATE FUNCTION mk_set_comment(on_ text, comment text) RETURNS text
2848
    LANGUAGE sql STABLE
2849
    AS $_$
2850
SELECT COALESCE($$COMMENT ON $$||$1||$$ IS $$
2851
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2852
$_$;
2853

    
2854

    
2855
--
2856
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2857
--
2858

    
2859
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2860
    LANGUAGE sql STABLE
2861
    AS $_$
2862
SELECT COALESCE($$COMMENT ON $$||util.relation_type($1)||$$ $$||$1||$$ IS $$
2863
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2864
$_$;
2865

    
2866

    
2867
--
2868
-- Name: mk_set_relation_metadata(regclass); Type: FUNCTION; Schema: util; Owner: -
2869
--
2870

    
2871
CREATE FUNCTION mk_set_relation_metadata(relation regclass) RETURNS text
2872
    LANGUAGE sql STABLE
2873
    AS $_$
2874
SELECT util.show_grants_for($1)
2875
||util.show_set_comment($1)||$$
2876
$$
2877
$_$;
2878

    
2879

    
2880
--
2881
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2882
--
2883

    
2884
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2885
    LANGUAGE sql IMMUTABLE
2886
    AS $_$
2887
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2888
$_$;
2889

    
2890

    
2891
--
2892
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2893
--
2894

    
2895
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2896
    LANGUAGE sql IMMUTABLE
2897
    AS $_$
2898
/* debug_print_return_value() needed because this function is used with EXECUTE
2899
rather than util.eval() (in order to affect the calling function), so the
2900
search_path would not otherwise be printed */
2901
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2902
||$$ search_path TO $$||$1
2903
$_$;
2904

    
2905

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

    
2910
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2911
    LANGUAGE sql
2912
    AS $_$
2913
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2914
$_$;
2915

    
2916

    
2917
--
2918
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2919
--
2920

    
2921
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2922
idempotent
2923
';
2924

    
2925

    
2926
--
2927
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2928
--
2929

    
2930
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2931
    LANGUAGE plpgsql STRICT
2932
    AS $_$
2933
DECLARE
2934
	view_qual_name text = util.qual_name(view_);
2935
BEGIN
2936
	EXECUTE $$
2937
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2938
  RETURNS SETOF $$||view_||$$ AS
2939
$BODY1$
2940
SELECT * FROM $$||view_qual_name||$$
2941
ORDER BY sort_col
2942
LIMIT $1 OFFSET $2
2943
$BODY1$
2944
  LANGUAGE sql STABLE
2945
  COST 100
2946
  ROWS 1000
2947
$$;
2948
	
2949
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2950
END;
2951
$_$;
2952

    
2953

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

    
2958
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2959
    LANGUAGE plpgsql STRICT
2960
    AS $_$
2961
DECLARE
2962
	view_qual_name text = util.qual_name(view_);
2963
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2964
BEGIN
2965
	EXECUTE $$
2966
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2967
  RETURNS integer AS
2968
$BODY1$
2969
SELECT $$||quote_ident(row_num_col)||$$
2970
FROM $$||view_qual_name||$$
2971
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2972
LIMIT 1
2973
$BODY1$
2974
  LANGUAGE sql STABLE
2975
  COST 100;
2976
$$;
2977
	
2978
	EXECUTE $$
2979
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2980
  RETURNS SETOF $$||view_||$$ AS
2981
$BODY1$
2982
SELECT * FROM $$||view_qual_name||$$
2983
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2984
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2985
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2986
ORDER BY $$||quote_ident(row_num_col)||$$
2987
$BODY1$
2988
  LANGUAGE sql STABLE
2989
  COST 100
2990
  ROWS 1000
2991
$$;
2992
	
2993
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2994
END;
2995
$_$;
2996

    
2997

    
2998
--
2999
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
3000
--
3001

    
3002
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
3003
    LANGUAGE plpgsql STRICT
3004
    AS $_$
3005
DECLARE
3006
	view_qual_name text = util.qual_name(view_);
3007
BEGIN
3008
	EXECUTE $$
3009
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
3010
  RETURNS SETOF $$||view_||$$
3011
  SET enable_sort TO 'off'
3012
  AS
3013
$BODY1$
3014
SELECT * FROM $$||view_qual_name||$$($2, $3)
3015
$BODY1$
3016
  LANGUAGE sql STABLE
3017
  COST 100
3018
  ROWS 1000
3019
;
3020
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
3021
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
3022
If you want to run EXPLAIN and get expanded output, use the regular subset
3023
function instead. (When a config param is set on a function, EXPLAIN produces
3024
just a function scan.)
3025
';
3026
$$;
3027
END;
3028
$_$;
3029

    
3030

    
3031
--
3032
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
3033
--
3034

    
3035
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
3036
creates subset function which turns off enable_sort
3037
';
3038

    
3039

    
3040
--
3041
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3042
--
3043

    
3044
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
3045
    LANGUAGE sql IMMUTABLE
3046
    AS $_$
3047
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
3048
util.qual_name((unnest).type), ', '), '')
3049
FROM unnest($1)
3050
$_$;
3051

    
3052

    
3053
--
3054
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
3055
--
3056

    
3057
CREATE FUNCTION name(table_ regclass) RETURNS text
3058
    LANGUAGE sql STABLE
3059
    AS $_$
3060
SELECT relname::text FROM pg_class WHERE oid = $1
3061
$_$;
3062

    
3063

    
3064
--
3065
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
3066
--
3067

    
3068
CREATE FUNCTION name(type regtype) RETURNS text
3069
    LANGUAGE sql STABLE
3070
    AS $_$
3071
SELECT typname::text FROM pg_type WHERE oid = $1
3072
$_$;
3073

    
3074

    
3075
--
3076
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
3077
--
3078

    
3079
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
3080
    LANGUAGE sql IMMUTABLE
3081
    AS $_$
3082
SELECT octet_length($1) >= util.namedatalen() - $2
3083
$_$;
3084

    
3085

    
3086
--
3087
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
3088
--
3089

    
3090
CREATE FUNCTION namedatalen() RETURNS integer
3091
    LANGUAGE sql IMMUTABLE
3092
    AS $$
3093
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
3094
$$;
3095

    
3096

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

    
3101
CREATE FUNCTION new_world() RETURNS postgis.geography
3102
    LANGUAGE sql IMMUTABLE
3103
    SET search_path TO util
3104
    AS $$
3105
SELECT util.bounding_box(-56 ~ 83, 172 ~ -34)
3106
$$;
3107

    
3108

    
3109
--
3110
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
3111
--
3112

    
3113
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
3114
    LANGUAGE sql IMMUTABLE
3115
    AS $_$
3116
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
3117
$_$;
3118

    
3119

    
3120
--
3121
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
3122
--
3123

    
3124
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
3125
    LANGUAGE sql IMMUTABLE
3126
    AS $_$
3127
SELECT $1 IS NOT NULL
3128
$_$;
3129

    
3130

    
3131
--
3132
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
3133
--
3134

    
3135
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
3136
    LANGUAGE sql IMMUTABLE
3137
    AS $_$
3138
SELECT util.hstore($1, NULL) || '*=>*'
3139
$_$;
3140

    
3141

    
3142
--
3143
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
3144
--
3145

    
3146
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
3147
for use with _map()
3148
';
3149

    
3150

    
3151
--
3152
-- Name: numrange(range); Type: FUNCTION; Schema: util; Owner: -
3153
--
3154

    
3155
CREATE FUNCTION numrange(value range) RETURNS numrange
3156
    LANGUAGE sql IMMUTABLE
3157
    AS $_$
3158
SELECT numrange($1.lower, $1.upper, $1.bounds)
3159
$_$;
3160

    
3161

    
3162
--
3163
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
3164
--
3165

    
3166
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
3167
    LANGUAGE sql IMMUTABLE
3168
    AS $_$
3169
SELECT $2 + COALESCE($1, 0)
3170
$_$;
3171

    
3172

    
3173
--
3174
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
3175
--
3176

    
3177
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
3178
    LANGUAGE sql STABLE
3179
    AS $_$
3180
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
3181
$_$;
3182

    
3183

    
3184
--
3185
-- Name: pg_get_viewdef(regclass); Type: FUNCTION; Schema: util; Owner: -
3186
--
3187

    
3188
CREATE FUNCTION pg_get_viewdef(view_ regclass) RETURNS text
3189
    LANGUAGE sql STABLE
3190
    AS $_$
3191
SELECT util.view_def_to_orig(pg_catalog.pg_get_viewdef($1))
3192
$_$;
3193

    
3194

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

    
3199
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
3200
    LANGUAGE sql
3201
    AS $_$
3202
SELECT util.eval($$INSERT INTO $$||$1||$$
3203
$$||util.ltrim_nl($2));
3204
-- make sure the created table has the correct estimated row count
3205
SELECT util.analyze_($1);
3206
$_$;
3207

    
3208

    
3209
--
3210
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
3211
--
3212

    
3213
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
3214
    LANGUAGE sql IMMUTABLE
3215
    AS $_$
3216
SELECT util.qual_name(util.schema($2), $1||util.name($2))
3217
$_$;
3218

    
3219

    
3220
--
3221
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3222
--
3223

    
3224
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
3225
    LANGUAGE sql
3226
    AS $_$
3227
SELECT util.set_comment($1, concat($2, util.comment($1)))
3228
$_$;
3229

    
3230

    
3231
--
3232
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
3233
--
3234

    
3235
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
3236
comment: must start and end with a newline
3237
';
3238

    
3239

    
3240
--
3241
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
3242
--
3243

    
3244
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
3245
    LANGUAGE sql IMMUTABLE
3246
    AS $_$
3247
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
3248
$_$;
3249

    
3250

    
3251
--
3252
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
3253
--
3254

    
3255
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
3256
    LANGUAGE sql STABLE
3257
    SET search_path TO pg_temp
3258
    AS $_$
3259
SELECT $1::text
3260
$_$;
3261

    
3262

    
3263
--
3264
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
3265
--
3266

    
3267
CREATE FUNCTION qual_name(type regtype) RETURNS text
3268
    LANGUAGE sql STABLE
3269
    SET search_path TO pg_temp
3270
    AS $_$
3271
SELECT $1::text
3272
$_$;
3273

    
3274

    
3275
--
3276
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
3277
--
3278

    
3279
COMMENT ON FUNCTION qual_name(type regtype) IS '
3280
a type''s schema-qualified name
3281
';
3282

    
3283

    
3284
--
3285
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
3286
--
3287

    
3288
CREATE FUNCTION qual_name(type unknown) RETURNS text
3289
    LANGUAGE sql STABLE
3290
    AS $_$
3291
SELECT util.qual_name($1::text::regtype)
3292
$_$;
3293

    
3294

    
3295
--
3296
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
3297
--
3298

    
3299
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
3300
    LANGUAGE sql IMMUTABLE
3301
    AS $_$
3302
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
3303
$_$;
3304

    
3305

    
3306
--
3307
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3308
--
3309

    
3310
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
3311
    LANGUAGE sql IMMUTABLE
3312
    AS $_$
3313
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
3314
$_$;
3315

    
3316

    
3317
--
3318
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
3319
--
3320

    
3321
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
3322
    LANGUAGE sql IMMUTABLE
3323
    AS $_$
3324
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
3325
$_$;
3326

    
3327

    
3328
--
3329
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
3330
--
3331

    
3332
CREATE FUNCTION raise(type text, msg text) RETURNS void
3333
    LANGUAGE sql IMMUTABLE
3334
    AS $_X$
3335
SELECT util.eval($$
3336
CREATE OR REPLACE FUNCTION pg_temp.__raise()
3337
  RETURNS void AS
3338
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
3339
$__BODY1$
3340
BEGIN
3341
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
3342
END;
3343
$__BODY1$
3344
  LANGUAGE plpgsql IMMUTABLE
3345
  COST 100;
3346
$$, verbose_ := false);
3347

    
3348
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
3349
$_X$;
3350

    
3351

    
3352
--
3353
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
3354
--
3355

    
3356
COMMENT ON FUNCTION raise(type text, msg text) IS '
3357
type: a log level from
3358
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
3359
or a condition name from
3360
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
3361
';
3362

    
3363

    
3364
--
3365
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
3366
--
3367

    
3368
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3369
    LANGUAGE sql IMMUTABLE
3370
    AS $_$
3371
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3372
$_$;
3373

    
3374

    
3375
--
3376
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3377
--
3378

    
3379
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3380
    LANGUAGE plpgsql IMMUTABLE STRICT
3381
    AS $$
3382
BEGIN
3383
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3384
END;
3385
$$;
3386

    
3387

    
3388
--
3389
-- Name: range(numeric, numeric); Type: FUNCTION; Schema: util; Owner: -
3390
--
3391

    
3392
CREATE FUNCTION range(lower numeric, upper numeric) RETURNS range
3393
    LANGUAGE sql IMMUTABLE
3394
    AS $_$
3395
SELECT ($1, $2, '[]')::util.range
3396
$_$;
3397

    
3398

    
3399
--
3400
-- Name: recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3401
--
3402

    
3403
CREATE FUNCTION recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
3404
    LANGUAGE plpgsql
3405
    AS $_$
3406
DECLARE
3407
	PG_EXCEPTION_DETAIL text;
3408
	restore_views_info util.restore_views_info;
3409
BEGIN
3410
	restore_views_info = util.save_drop_views(users);
3411
	
3412
	-- trigger the dependent_objects_still_exist exception
3413
	PERFORM util.eval(COALESCE(util.mk_drop_from_create(cmd), '')||cmd);
3414
		-- *not* CASCADE; it must trigger an exception
3415
	
3416
	PERFORM util.restore_views(restore_views_info);
3417
EXCEPTION
3418
WHEN dependent_objects_still_exist THEN
3419
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
3420
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
3421
	users = array(SELECT * FROM util.regexp_matches_group(
3422
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$'));
3423
		-- will be in forward dependency order
3424
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
3425
	PERFORM util.debug_print_var('users', users);
3426
	IF util.is_empty(users) THEN RAISE; END IF;
3427
	PERFORM util.recreate(cmd, users);
3428
END;
3429
$_$;
3430

    
3431

    
3432
--
3433
-- Name: FUNCTION recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
3434
--
3435

    
3436
COMMENT ON FUNCTION recreate(cmd text, users text[]) IS '
3437
the appropriate drop statement will be added automatically.
3438

    
3439
usage:
3440
SELECT util.recreate($$
3441
CREATE VIEW schema.main_view AS _;
3442

    
3443
-- manually restore views that need to be updated for the changes
3444
CREATE VIEW schema.dependent_view AS _;
3445
$$);
3446

    
3447
idempotent
3448

    
3449
users: not necessary to provide this because it will be autopopulated
3450
';
3451

    
3452

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

    
3457
CREATE FUNCTION recreate_view(view_ regclass, view_query text DEFAULT NULL::text, dependent_view_changes text DEFAULT ''::text) RETURNS void
3458
    LANGUAGE sql
3459
    AS $_$
3460
SELECT util.recreate($$
3461
CREATE VIEW $$||$1||$$ AS 
3462
$$||COALESCE($2, pg_get_viewdef($1))||$$;
3463
$$||util.mk_set_relation_metadata($1)||$$
3464

    
3465
-- manually restore views that need to be updated for the changes
3466
$$||$3||$$
3467
$$);
3468
$_$;
3469

    
3470

    
3471
--
3472
-- Name: FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text); Type: COMMENT; Schema: util; Owner: -
3473
--
3474

    
3475
COMMENT ON FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text) IS '
3476
usage:
3477
SELECT util.recreate_view(''schema.main_view'', $$
3478
SELECT __
3479
$$, $$
3480
CREATE VIEW schema.dependent_view AS 
3481
__;
3482
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3483
$$);
3484

    
3485
if view has already been modified:
3486
SELECT util.recreate_view(''schema.main_view'', dependent_view_changes := $$
3487
CREATE VIEW schema.dependent_view AS 
3488
__;
3489
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3490
$$);
3491

    
3492
idempotent
3493
';
3494

    
3495

    
3496
--
3497
-- Name: regexp_match(text, text); Type: FUNCTION; Schema: util; Owner: -
3498
--
3499

    
3500
CREATE FUNCTION regexp_match(str text, re text) RETURNS text[]
3501
    LANGUAGE sql IMMUTABLE
3502
    AS $_$
3503
SELECT match FROM regexp_matches($1, $2) match LIMIT 1/*only 1st match*/
3504
$_$;
3505

    
3506

    
3507
--
3508
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3509
--
3510

    
3511
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3512
    LANGUAGE sql IMMUTABLE
3513
    AS $_$
3514
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3515
$_$;
3516

    
3517

    
3518
--
3519
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3520
--
3521

    
3522
CREATE FUNCTION regexp_quote(str text) RETURNS text
3523
    LANGUAGE sql IMMUTABLE
3524
    AS $_$
3525
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3526
$_$;
3527

    
3528

    
3529
--
3530
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
3531
--
3532

    
3533
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3534
    LANGUAGE sql IMMUTABLE
3535
    AS $_$
3536
SELECT (CASE WHEN right($1, 1) = ')'
3537
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3538
$_$;
3539

    
3540

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

    
3545
CREATE FUNCTION relation_exists(relation text) RETURNS boolean
3546
    LANGUAGE sql STABLE
3547
    AS $_$
3548
SELECT $1 IS NOT NULL AND util.is_castable($1, NULL::regclass)
3549
$_$;
3550

    
3551

    
3552
--
3553
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3554
--
3555

    
3556
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3557
    LANGUAGE sql STABLE
3558
    AS $_$
3559
SELECT util.relation_type(util.relation_type_char($1))
3560
$_$;
3561

    
3562

    
3563
--
3564
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3565
--
3566

    
3567
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3568
    LANGUAGE sql IMMUTABLE
3569
    AS $_$
3570
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3571
$_$;
3572

    
3573

    
3574
--
3575
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3576
--
3577

    
3578
CREATE FUNCTION relation_type(type regtype) RETURNS text
3579
    LANGUAGE sql IMMUTABLE
3580
    AS $$
3581
SELECT 'TYPE'::text
3582
$$;
3583

    
3584

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

    
3589
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3590
    LANGUAGE sql STABLE
3591
    AS $_$
3592
SELECT relkind FROM pg_class WHERE oid = $1
3593
$_$;
3594

    
3595

    
3596
--
3597
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
3598
--
3599

    
3600
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3601
    LANGUAGE sql
3602
    AS $_$
3603
/* can't have in_table/out_table inherit from *each other*, because inheritance
3604
also causes the rows of the parent table to be included in the child table.
3605
instead, they need to inherit from a common, empty table. */
3606
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3607
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3608
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3609
SELECT util.inherit($2, $4);
3610
SELECT util.inherit($3, $4);
3611

    
3612
SELECT util.rematerialize_query($1, $$
3613
SELECT * FROM util.diff(
3614
  $$||util.quote_typed($2)||$$
3615
, $$||util.quote_typed($3)||$$
3616
, NULL::$$||$4||$$)
3617
$$);
3618

    
3619
/* the table unfortunately cannot be *materialized* in human-readable form,
3620
because this would create column name collisions between the two sides */
3621
SELECT util.prepend_comment($1, '
3622
to view this table in human-readable form (with each side''s tuple column
3623
expanded to its component fields):
3624
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3625

    
3626
to display NULL values that are extra or missing:
3627
SELECT * FROM '||$1||';
3628
');
3629
$_$;
3630

    
3631

    
3632
--
3633
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3634
--
3635

    
3636
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3637
type_table (*required*): table to create as the shared base type
3638
';
3639

    
3640

    
3641
--
3642
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3643
--
3644

    
3645
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3646
    LANGUAGE sql
3647
    AS $_$
3648
SELECT util.drop_table($1);
3649
SELECT util.materialize_query($1, $2);
3650
$_$;
3651

    
3652

    
3653
--
3654
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3655
--
3656

    
3657
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3658
idempotent, but repeats action each time
3659
';
3660

    
3661

    
3662
--
3663
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3664
--
3665

    
3666
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3667
    LANGUAGE sql
3668
    AS $_$
3669
SELECT util.drop_table($1);
3670
SELECT util.materialize_view($1, $2);
3671
$_$;
3672

    
3673

    
3674
--
3675
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3676
--
3677

    
3678
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3679
idempotent, but repeats action each time
3680
';
3681

    
3682

    
3683
--
3684
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3685
--
3686

    
3687
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3688
    LANGUAGE sql
3689
    AS $_$
3690
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3691
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3692
FROM util.col_names($1::text::regtype) f (name);
3693
SELECT NULL::void; -- don't fold away functions called in previous query
3694
$_$;
3695

    
3696

    
3697
--
3698
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3699
--
3700

    
3701
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3702
idempotent
3703
';
3704

    
3705

    
3706
--
3707
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3708
--
3709

    
3710
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3711
    LANGUAGE sql
3712
    AS $_$
3713
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3714
included in the debug SQL */
3715
SELECT util.rename_relation(util.qual_name($1), $2)
3716
$_$;
3717

    
3718

    
3719
--
3720
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3721
--
3722

    
3723
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3724
    LANGUAGE sql
3725
    AS $_$
3726
/* 'ALTER TABLE can be used with views too'
3727
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3728
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3729
||quote_ident($2))
3730
$_$;
3731

    
3732

    
3733
--
3734
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3735
--
3736

    
3737
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3738
idempotent
3739
';
3740

    
3741

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

    
3746
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3747
    LANGUAGE sql IMMUTABLE
3748
    AS $_$
3749
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3750
$_$;
3751

    
3752

    
3753
--
3754
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3755
--
3756

    
3757
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3758
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 
3759
';
3760

    
3761

    
3762
--
3763
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3764
--
3765

    
3766
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3767
    LANGUAGE sql
3768
    AS $_$
3769
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3770
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3771
SELECT util.set_col_names($1, $2);
3772
$_$;
3773

    
3774

    
3775
--
3776
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3777
--
3778

    
3779
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3780
idempotent.
3781
alters the names table, so it will need to be repopulated after running this function.
3782
';
3783

    
3784

    
3785
--
3786
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3787
--
3788

    
3789
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3790
    LANGUAGE sql
3791
    AS $_$
3792
SELECT util.drop_table($1);
3793
SELECT util.mk_map_table($1);
3794
$_$;
3795

    
3796

    
3797
--
3798
-- Name: restore_views(restore_views_info); Type: FUNCTION; Schema: util; Owner: -
3799
--
3800

    
3801
CREATE FUNCTION restore_views(restore_views_info) RETURNS void
3802
    LANGUAGE sql
3803
    AS $_$
3804
SELECT util.debug_print_var('views', $1);
3805
SELECT util.create_if_not_exists((view_).def, (view_).path)
3806
	/* need to specify view name for manual existence check, in case view def
3807
	becomes invalid, which would produce nonstandard (uncatchable) exception */
3808
FROM unnest($1.views) view_; -- in forward dependency order
3809
	/* create_if_not_exists() rather than eval(), because cmd might manually
3810
	re-create a deleted dependent view, causing it to already exist */
3811
SELECT NULL::void; -- don't fold away functions called in previous query
3812
$_$;
3813

    
3814

    
3815
--
3816
-- Name: rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
3817
--
3818

    
3819
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3820
    LANGUAGE sql
3821
    AS $_$
3822
SELECT util.drop_column($1, $2, force := true)
3823
$_$;
3824

    
3825

    
3826
--
3827
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3828
--
3829

    
3830
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3831
    LANGUAGE sql IMMUTABLE
3832
    AS $_$
3833
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3834
$_$;
3835

    
3836

    
3837
--
3838
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3839
--
3840

    
3841
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3842
    LANGUAGE sql IMMUTABLE
3843
    AS $_$
3844
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3845
ELSE util.mk_set_search_path(for_printing := true)||$$;
3846
$$ END)||$1
3847
$_$;
3848

    
3849

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

    
3854
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3855
    LANGUAGE plpgsql STRICT
3856
    AS $$
3857
DECLARE
3858
	result text = NULL;
3859
BEGIN
3860
	BEGIN
3861
		result = util.show_create_view(view_, replace := false);
3862
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3863
			(eg. invalid_table_definition), instead of the standard
3864
			duplicate_table exception caught by util.create_if_not_exists() */
3865
		PERFORM util.drop_view(view_);
3866
	EXCEPTION
3867
		WHEN undefined_table THEN NULL;
3868
	END;
3869
	RETURN result;
3870
END;
3871
$$;
3872

    
3873

    
3874
--
3875
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3876
--
3877

    
3878
CREATE FUNCTION save_drop_views(views text[]) RETURNS restore_views_info
3879
    LANGUAGE sql
3880
    AS $_$
3881
SELECT ROW(/*return in forward dependency order*/util.array_reverse(array(
3882
SELECT (view_, util.save_drop_view(view_))::util.db_item
3883
FROM unnest(/*drop in reverse dependency order*/util.array_reverse($1)) view_
3884
)))::util.restore_views_info
3885
$_$;
3886

    
3887

    
3888
--
3889
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3890
--
3891

    
3892
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3893
    LANGUAGE sql STABLE
3894
    AS $_$
3895
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3896
$_$;
3897

    
3898

    
3899
--
3900
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3901
--
3902

    
3903
CREATE FUNCTION schema(table_ regclass) RETURNS text
3904
    LANGUAGE sql STABLE
3905
    AS $_$
3906
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3907
$_$;
3908

    
3909

    
3910
--
3911
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3912
--
3913

    
3914
CREATE FUNCTION schema(type regtype) RETURNS text
3915
    LANGUAGE sql STABLE
3916
    AS $_$
3917
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3918
$_$;
3919

    
3920

    
3921
--
3922
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3923
--
3924

    
3925
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3926
    LANGUAGE sql STABLE
3927
    AS $_$
3928
SELECT util.schema(pg_typeof($1))
3929
$_$;
3930

    
3931

    
3932
--
3933
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3934
--
3935

    
3936
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3937
    LANGUAGE sql STABLE
3938
    AS $_$
3939
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3940
$_$;
3941

    
3942

    
3943
--
3944
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3945
--
3946

    
3947
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3948
a schema bundle is a group of schemas with a common prefix
3949
';
3950

    
3951

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

    
3956
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3957
    LANGUAGE sql
3958
    AS $_$
3959
SELECT util.schema_rename(old_schema,
3960
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3961
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3962
SELECT NULL::void; -- don't fold away functions called in previous query
3963
$_$;
3964

    
3965

    
3966
--
3967
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3968
--
3969

    
3970
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3971
    LANGUAGE plpgsql
3972
    AS $$
3973
BEGIN
3974
	-- don't schema_bundle_rm() the schema_bundle to keep!
3975
	IF replace = with_ THEN RETURN; END IF;
3976
	
3977
	PERFORM util.schema_bundle_rm(replace);
3978
	PERFORM util.schema_bundle_rename(with_, replace);
3979
END;
3980
$$;
3981

    
3982

    
3983
--
3984
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3985
--
3986

    
3987
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3988
    LANGUAGE sql
3989
    AS $_$
3990
SELECT util.schema_rm(schema)
3991
FROM util.schema_bundle_get_schemas($1) f (schema);
3992
SELECT NULL::void; -- don't fold away functions called in previous query
3993
$_$;
3994

    
3995

    
3996
--
3997
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3998
--
3999

    
4000
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
4001
    LANGUAGE sql STABLE
4002
    AS $_$
4003
SELECT quote_ident(util.schema($1))
4004
$_$;
4005

    
4006

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

    
4011
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
4012
    LANGUAGE sql IMMUTABLE
4013
    AS $_$
4014
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
4015
$_$;
4016

    
4017

    
4018
--
4019
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
4020
--
4021

    
4022
CREATE FUNCTION schema_oid(schema text) RETURNS oid
4023
    LANGUAGE sql STABLE
4024
    AS $_$
4025
SELECT oid FROM pg_namespace WHERE nspname = $1
4026
$_$;
4027

    
4028

    
4029
--
4030
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
4031
--
4032

    
4033
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
4034
    LANGUAGE sql IMMUTABLE
4035
    AS $_$
4036
SELECT util.schema_regexp(schema_anchor := $1)
4037
$_$;
4038

    
4039

    
4040
--
4041
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
4042
--
4043

    
4044
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
4045
    LANGUAGE sql IMMUTABLE
4046
    AS $_$
4047
SELECT util.str_equality_regexp(util.schema($1))
4048
$_$;
4049

    
4050

    
4051
--
4052
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
4053
--
4054

    
4055
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
4056
    LANGUAGE sql
4057
    AS $_$
4058
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
4059
$_$;
4060

    
4061

    
4062
--
4063
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
4064
--
4065

    
4066
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
4067
    LANGUAGE plpgsql
4068
    AS $$
4069
BEGIN
4070
	-- don't schema_rm() the schema to keep!
4071
	IF replace = with_ THEN RETURN; END IF;
4072
	
4073
	PERFORM util.schema_rm(replace);
4074
	PERFORM util.schema_rename(with_, replace);
4075
END;
4076
$$;
4077

    
4078

    
4079
--
4080
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
4081
--
4082

    
4083
CREATE FUNCTION schema_rm(schema text) RETURNS void
4084
    LANGUAGE sql
4085
    AS $_$
4086
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
4087
$_$;
4088

    
4089

    
4090
--
4091
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
4092
--
4093

    
4094
CREATE FUNCTION search_path_append(schemas text) RETURNS void
4095
    LANGUAGE sql
4096
    AS $_$
4097
SELECT util.eval(
4098
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
4099
$_$;
4100

    
4101

    
4102
--
4103
-- Name: seq__create(text, integer); Type: FUNCTION; Schema: util; Owner: -
4104
--
4105

    
4106
CREATE FUNCTION seq__create(seq text, start integer DEFAULT 0) RETURNS void
4107
    LANGUAGE sql
4108
    AS $_$
4109
SELECT util.create_if_not_exists($$CREATE SEQUENCE $$||$1||$$ MINVALUE $$||$2,
4110
$1)
4111
$_$;
4112

    
4113

    
4114
--
4115
-- Name: FUNCTION seq__create(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
4116
--
4117

    
4118
COMMENT ON FUNCTION seq__create(seq text, start integer) IS '
4119
idempotent
4120
';
4121

    
4122

    
4123
--
4124
-- Name: seq__reset(text, integer); Type: FUNCTION; Schema: util; Owner: -
4125
--
4126

    
4127
CREATE FUNCTION seq__reset(seq text, start integer DEFAULT 0) RETURNS void
4128
    LANGUAGE sql
4129
    AS $_$
4130
SELECT util.seq__create($1, $2);
4131
SELECT util.eval($$ALTER SEQUENCE $$||$1||$$ RESTART$$);
4132
$_$;
4133

    
4134

    
4135
--
4136
-- Name: FUNCTION seq__reset(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
4137
--
4138

    
4139
COMMENT ON FUNCTION seq__reset(seq text, start integer) IS '
4140
creates sequence if doesn''t exist
4141

    
4142
idempotent
4143

    
4144
start: *note*: only used if sequence doesn''t exist
4145
';
4146

    
4147

    
4148
--
4149
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
4150
--
4151

    
4152
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
4153
    LANGUAGE plpgsql STRICT
4154
    AS $_$
4155
DECLARE
4156
    old text[] = ARRAY(SELECT util.col_names(table_));
4157
    new text[] = ARRAY(SELECT util.map_values(names));
4158
BEGIN
4159
    old = old[1:array_length(new, 1)]; -- truncate to same length
4160
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
4161
||$$ TO $$||quote_ident(value))
4162
    FROM each(hstore(old, new))
4163
    WHERE value != key -- not same name
4164
    ;
4165
END;
4166
$_$;
4167

    
4168

    
4169
--
4170
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
4171
--
4172

    
4173
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
4174
idempotent
4175
';
4176

    
4177

    
4178
--
4179
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
4180
--
4181

    
4182
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
4183
    LANGUAGE plpgsql STRICT
4184
    AS $_$
4185
DECLARE
4186
	row_ util.map;
4187
BEGIN
4188
	-- rename any metadata cols rather than re-adding them with new names
4189
	BEGIN
4190
		PERFORM util.set_col_names(table_, names);
4191
	EXCEPTION
4192
		WHEN array_subscript_error THEN -- selective suppress
4193
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
4194
				-- metadata cols not yet added
4195
			ELSE RAISE;
4196
			END IF;
4197
	END;
4198
	
4199
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
4200
	LOOP
4201
		PERFORM util.mk_const_col((table_, row_."to"),
4202
			substring(row_."from" from 2));
4203
	END LOOP;
4204
	
4205
	PERFORM util.set_col_names(table_, names);
4206
END;
4207
$_$;
4208

    
4209

    
4210
--
4211
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
4212
--
4213

    
4214
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
4215
idempotent.
4216
the metadata mappings must be *last* in the names table.
4217
';
4218

    
4219

    
4220
--
4221
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
4222
--
4223

    
4224
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
4225
    LANGUAGE sql
4226
    AS $_$
4227
SELECT util.eval(COALESCE(
4228
$$ALTER TABLE $$||$1||$$
4229
$$||(
4230
	SELECT
4231
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
4232
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
4233
, $$)
4234
	FROM
4235
	(
4236
		SELECT
4237
		  quote_ident(col_name) AS col_name_sql
4238
		, util.col_type(($1, col_name)) AS curr_type
4239
		, type AS target_type
4240
		FROM unnest($2)
4241
	) s
4242
	WHERE curr_type != target_type
4243
), ''))
4244
$_$;
4245

    
4246

    
4247
--
4248
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
4249
--
4250

    
4251
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
4252
idempotent
4253
';
4254

    
4255

    
4256
--
4257
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4258
--
4259

    
4260
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
4261
    LANGUAGE sql
4262
    AS $_$
4263
SELECT util.eval(util.mk_set_comment($1, $2))
4264
$_$;
4265

    
4266

    
4267
--
4268
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
4269
--
4270

    
4271
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
4272
    LANGUAGE sql
4273
    AS $_$
4274
SELECT util.eval(util.mk_set_search_path($1, $2))
4275
$_$;
4276

    
4277

    
4278
--
4279
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4280
--
4281

    
4282
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
4283
    LANGUAGE sql STABLE
4284
    AS $_$
4285
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
4286
||$1||$$ AS
4287
$$||util.pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
4288
$$||util.mk_set_relation_metadata($1)
4289
$_$;
4290

    
4291

    
4292
--
4293
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
4294
--
4295

    
4296
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
4297
    LANGUAGE sql STABLE
4298
    AS $_$
4299
SELECT string_agg(cmd, '')
4300
FROM
4301
(
4302
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
4303
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
4304
$$ ELSE '' END) AS cmd
4305
	FROM util.grants_users() f (user_)
4306
) s
4307
$_$;
4308

    
4309

    
4310
--
4311
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
4312
--
4313

    
4314
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
4315
    LANGUAGE sql STABLE
4316
    AS $_$
4317
SELECT oid FROM pg_class
4318
WHERE relkind = ANY($3) AND relname ~ $1
4319
AND util.schema_matches(util.schema(relnamespace), $2)
4320
ORDER BY relname
4321
$_$;
4322

    
4323

    
4324
--
4325
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
4326
--
4327

    
4328
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
4329
    LANGUAGE sql STABLE
4330
    AS $_$
4331
SELECT util.mk_set_comment($1, util.comment($1))
4332
$_$;
4333

    
4334

    
4335
--
4336
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4337
--
4338

    
4339
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
4340
    LANGUAGE sql STABLE
4341
    AS $_$
4342
SELECT oid
4343
FROM pg_type
4344
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
4345
ORDER BY typname
4346
$_$;
4347

    
4348

    
4349
--
4350
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4351
--
4352

    
4353
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
4354
    LANGUAGE sql STABLE
4355
    AS $_$
4356
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
4357
$_$;
4358

    
4359

    
4360
--
4361
-- Name: south_america(); Type: FUNCTION; Schema: util; Owner: -
4362
--
4363

    
4364
CREATE FUNCTION south_america() RETURNS postgis.geometry
4365
    LANGUAGE sql IMMUTABLE
4366
    SET search_path TO util
4367
    AS $$
4368
SELECT util.bounding_box__no_dateline(-56 ~ 13, -82 ~ -34)
4369
$$;
4370

    
4371

    
4372
--
4373
-- Name: sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
4374
--
4375

    
4376
CREATE FUNCTION sql(col col_ref) RETURNS text
4377
    LANGUAGE sql STABLE
4378
    AS $_$
4379
SELECT $1.table_||'.'||quote_ident($1.name)
4380
$_$;
4381

    
4382

    
4383
--
4384
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
4385
--
4386

    
4387
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
4388
    LANGUAGE sql IMMUTABLE
4389
    AS $_$
4390
SELECT '^'||util.regexp_quote($1)||'$'
4391
$_$;
4392

    
4393

    
4394
--
4395
-- Name: subspecies(text); Type: FUNCTION; Schema: util; Owner: -
4396
--
4397

    
4398
CREATE FUNCTION subspecies(taxon_name text) RETURNS text
4399
    LANGUAGE sql IMMUTABLE
4400
    AS $_$
4401
SELECT (regexp_matches($1, '\ysubsp\. (\S+)'))[1]
4402
$_$;
4403

    
4404

    
4405
--
4406
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
4407
--
4408

    
4409
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
4410
    LANGUAGE plpgsql STABLE STRICT
4411
    AS $_$
4412
DECLARE
4413
    hstore hstore;
4414
BEGIN
4415
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
4416
        table_||$$))$$ INTO STRICT hstore;
4417
    RETURN hstore;
4418
END;
4419
$_$;
4420

    
4421

    
4422
--
4423
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4424
--
4425

    
4426
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
4427
    LANGUAGE sql STABLE
4428
    AS $_$
4429
SELECT COUNT(*) > 0 FROM pg_constraint
4430
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
4431
$_$;
4432

    
4433

    
4434
--
4435
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4436
--
4437

    
4438
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
4439
gets whether a status flag is set by the presence of a table constraint
4440
';
4441

    
4442

    
4443
--
4444
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4445
--
4446

    
4447
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
4448
    LANGUAGE sql
4449
    AS $_$
4450
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
4451
||quote_ident($2)||$$ CHECK (true)$$)
4452
$_$;
4453

    
4454

    
4455
--
4456
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4457
--
4458

    
4459
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
4460
stores a status flag by the presence of a table constraint.
4461
idempotent.
4462
';
4463

    
4464

    
4465
--
4466
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
4467
--
4468

    
4469
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
4470
    LANGUAGE sql STABLE
4471
    AS $_$
4472
SELECT util.table_flag__get($1, 'nulls_mapped')
4473
$_$;
4474

    
4475

    
4476
--
4477
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4478
--
4479

    
4480
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
4481
gets whether a table''s NULL-equivalent strings have been replaced with NULL
4482
';
4483

    
4484

    
4485
--
4486
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
4487
--
4488

    
4489
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
4490
    LANGUAGE sql
4491
    AS $_$
4492
SELECT util.table_flag__set($1, 'nulls_mapped')
4493
$_$;
4494

    
4495

    
4496
--
4497
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4498
--
4499

    
4500
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
4501
sets that a table''s NULL-equivalent strings have been replaced with NULL.
4502
idempotent.
4503
';
4504

    
4505

    
4506
--
4507
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
4508
--
4509

    
4510
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
4511
    LANGUAGE sql
4512
    AS $_$
4513
-- save data before truncating main table
4514
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
4515

    
4516
-- repopulate main table w/ copies column
4517
SELECT util.truncate($1);
4518
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
4519
SELECT util.populate_table($1, $$
4520
SELECT (table_).*, copies
4521
FROM (
4522
	SELECT table_, COUNT(*) AS copies
4523
	FROM pg_temp.__copy table_
4524
	GROUP BY table_
4525
) s
4526
$$);
4527

    
4528
-- delete temp table so it doesn't stay around until end of connection
4529
SELECT util.drop_table('pg_temp.__copy');
4530
$_$;
4531

    
4532

    
4533
--
4534
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
4535
--
4536

    
4537
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
4538
    LANGUAGE plpgsql STRICT
4539
    AS $_$
4540
DECLARE
4541
    row record;
4542
BEGIN
4543
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
4544
    LOOP
4545
        IF row.global_name != row.name THEN
4546
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
4547
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
4548
        END IF;
4549
    END LOOP;
4550
END;
4551
$_$;
4552

    
4553

    
4554
--
4555
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4556
--
4557

    
4558
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
4559
idempotent
4560
';
4561

    
4562

    
4563
--
4564
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4565
--
4566

    
4567
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
4568
    LANGUAGE sql
4569
    AS $_$
4570
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
4571
SELECT NULL::void; -- don't fold away functions called in previous query
4572
$_$;
4573

    
4574

    
4575
--
4576
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
4577
--
4578

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

    
4582
by default, cascadingly drops dependent columns so that they don''t prevent
4583
trim() from succeeding. note that this requires the dependent columns to then be
4584
manually re-created.
4585

    
4586
idempotent
4587
';
4588

    
4589

    
4590
--
4591
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4592
--
4593

    
4594
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4595
    LANGUAGE plpgsql STRICT
4596
    AS $_$
4597
BEGIN
4598
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4599
END;
4600
$_$;
4601

    
4602

    
4603
--
4604
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4605
--
4606

    
4607
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4608
idempotent
4609
';
4610

    
4611

    
4612
--
4613
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4614
--
4615

    
4616
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4617
    LANGUAGE sql IMMUTABLE
4618
    AS $_$
4619
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4620
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4621
$_$;
4622

    
4623

    
4624
--
4625
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4626
--
4627

    
4628
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4629
    LANGUAGE plpgsql IMMUTABLE
4630
    AS $$
4631
BEGIN
4632
	/* need explicit cast because some types not implicitly-castable, and also
4633
	to make the cast happen inside the try block. (*implicit* casts to the
4634
	return type happen at the end of the function, outside any block.) */
4635
	RETURN util.cast(value, ret_type_null);
4636
EXCEPTION
4637
WHEN   data_exception
4638
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
4639
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
4640
	THEN
4641
	PERFORM util.raise('WARNING', SQLERRM);
4642
	RETURN NULL;
4643
END;
4644
$$;
4645

    
4646

    
4647
--
4648
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4649
--
4650

    
4651
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4652
ret_type_null: NULL::ret_type
4653
';
4654

    
4655

    
4656
--
4657
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4658
--
4659

    
4660
CREATE FUNCTION try_create(sql text) RETURNS void
4661
    LANGUAGE plpgsql STRICT
4662
    AS $$
4663
BEGIN
4664
	PERFORM util.eval(sql);
4665
EXCEPTION
4666
WHEN   not_null_violation
4667
		/* trying to add NOT NULL column to parent table, which cascades to
4668
		child table whose values for the new column will be NULL */
4669
	OR wrong_object_type -- trying to alter a view's columns
4670
	OR undefined_column
4671
	OR duplicate_column
4672
THEN NULL;
4673
WHEN datatype_mismatch THEN
4674
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4675
	ELSE RAISE; -- rethrow
4676
	END IF;
4677
END;
4678
$$;
4679

    
4680

    
4681
--
4682
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4683
--
4684

    
4685
COMMENT ON FUNCTION try_create(sql text) IS '
4686
idempotent
4687
';
4688

    
4689

    
4690
--
4691
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4692
--
4693

    
4694
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4695
    LANGUAGE sql
4696
    AS $_$
4697
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4698
$_$;
4699

    
4700

    
4701
--
4702
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4703
--
4704

    
4705
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4706
idempotent
4707
';
4708

    
4709

    
4710
--
4711
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4712
--
4713

    
4714
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4715
    LANGUAGE sql IMMUTABLE
4716
    AS $_$
4717
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4718
$_$;
4719

    
4720

    
4721
--
4722
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4723
--
4724

    
4725
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4726
a type''s NOT NULL qualifier
4727
';
4728

    
4729

    
4730
--
4731
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4732
--
4733

    
4734
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4735
    LANGUAGE sql STABLE
4736
    AS $_$
4737
SELECT (attname::text, atttypid)::util.col_cast
4738
FROM pg_attribute
4739
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4740
ORDER BY attnum
4741
$_$;
4742

    
4743

    
4744
--
4745
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4746
--
4747

    
4748
CREATE FUNCTION typeof(value anyelement) RETURNS text
4749
    LANGUAGE sql IMMUTABLE
4750
    AS $_$
4751
SELECT util.qual_name(pg_typeof($1))
4752
$_$;
4753

    
4754

    
4755
--
4756
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4757
--
4758

    
4759
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4760
    LANGUAGE plpgsql STABLE
4761
    AS $_$
4762
DECLARE
4763
    type regtype;
4764
BEGIN
4765
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4766
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4767
    RETURN type;
4768
END;
4769
$_$;
4770

    
4771

    
4772
--
4773
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4774
--
4775

    
4776
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4777
    LANGUAGE sql
4778
    AS $_$
4779
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4780
$_$;
4781

    
4782

    
4783
--
4784
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4785
--
4786

    
4787
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4788
auto-appends util to the search_path to enable use of util operators
4789
';
4790

    
4791

    
4792
--
4793
-- Name: view_def_to_orig(text); Type: FUNCTION; Schema: util; Owner: -
4794
--
4795

    
4796
CREATE FUNCTION view_def_to_orig(view_def text) RETURNS text
4797
    LANGUAGE sql IMMUTABLE
4798
    AS $_$
4799
SELECT CASE
4800
WHEN util.view_is_subset($1) THEN $1
4801
	-- list of cols from the same table is not an expanded * expression
4802
ELSE
4803
regexp_replace(
4804
regexp_replace(
4805
$1
4806
,
4807
/* unexpand expanded * expressions. any list of 6+ cols from the same table is
4808
treated as a * expression. */
4809
'((?:"[^"\s]+"|\w+)\.)(?:"[^"\s]+"|\w+)'||
4810
	/* 1st col, which lacks separator before.
4811
	*note*: can't prepend \y because it considers only \w chars, not " */
4812
'(,[[:blank:]]*
4813
[[:blank:]]*)\1(?:"[^"\s]+"|\w+)'|| -- 2nd col, which has separator before
4814
'(?:\2\1(?:"[^"\s]+"|\w+)){4,}', -- later cols, w/ same table name and separator
4815
'\1*'/*prefix w/ table*/,
4816
'g')
4817
,
4818
/* merge .* expressions resulting from a SELECT * of a join. any list of
4819
multiple .* expressions is treated as a SELECT * . */
4820
'(?:"[^"\s]+"|\w+)\.\*'||
4821
	/* 1st table, which lacks separator before.
4822
	*note*: can't prepend \y because it considers only \w chars, not " */
4823
'(,[[:blank:]]*
4824
[[:blank:]]*)(?:"[^"\s]+"|\w+)\.\*'|| -- 2nd table, which has separator before
4825
'(?:\1(?:"[^"\s]+"|\w+)\.\*)*', -- later tables, w/ same separator
4826
'*',
4827
'g')
4828
END
4829
$_$;
4830

    
4831

    
4832
--
4833
-- Name: view_is_automatically_updatable(text); Type: FUNCTION; Schema: util; Owner: -
4834
--
4835

    
4836
CREATE FUNCTION view_is_automatically_updatable(view_def text) RETURNS boolean
4837
    LANGUAGE sql IMMUTABLE
4838
    AS $_$
4839
SELECT $1 !~ '\y(?:JOIN|WITH|DISTINCT|GROUP BY|HAVING|LIMIT|OFFSET)\y'
4840
	/* from http://www.postgresql.org/docs/9.3/static/sql-createview.html#SQL-CREATEVIEW-UPDATABLE-VIEWS */
4841
$_$;
4842

    
4843

    
4844
--
4845
-- Name: view_is_subset(text); Type: FUNCTION; Schema: util; Owner: -
4846
--
4847

    
4848
CREATE FUNCTION view_is_subset(view_def text) RETURNS boolean
4849
    LANGUAGE sql IMMUTABLE
4850
    AS $_$
4851
SELECT util.view_is_automatically_updatable($1)
4852
$_$;
4853

    
4854

    
4855
--
4856
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4857
--
4858

    
4859
CREATE AGGREGATE all_same(anyelement) (
4860
    SFUNC = all_same_transform,
4861
    STYPE = anyarray,
4862
    FINALFUNC = all_same_final
4863
);
4864

    
4865

    
4866
--
4867
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4868
--
4869

    
4870
COMMENT ON AGGREGATE all_same(anyelement) IS '
4871
includes NULLs in comparison
4872
';
4873

    
4874

    
4875
--
4876
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4877
--
4878

    
4879
CREATE AGGREGATE join_strs(text, text) (
4880
    SFUNC = join_strs_transform,
4881
    STYPE = text
4882
);
4883

    
4884

    
4885
--
4886
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4887
--
4888

    
4889
CREATE OPERATOR %== (
4890
    PROCEDURE = keys_eq,
4891
    LEFTARG = anyelement,
4892
    RIGHTARG = anyelement
4893
);
4894

    
4895

    
4896
--
4897
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4898
--
4899

    
4900
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4901
returns whether the map-keys of the compared values are the same
4902
(mnemonic: % is the Perl symbol for a hash map)
4903

    
4904
should be overridden for types that store both keys and values
4905

    
4906
used in a FULL JOIN to select which columns to join on
4907
';
4908

    
4909

    
4910
--
4911
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4912
--
4913

    
4914
CREATE OPERATOR -> (
4915
    PROCEDURE = map_get,
4916
    LEFTARG = regclass,
4917
    RIGHTARG = text
4918
);
4919

    
4920

    
4921
--
4922
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4923
--
4924

    
4925
CREATE OPERATOR => (
4926
    PROCEDURE = hstore,
4927
    LEFTARG = text[],
4928
    RIGHTARG = text
4929
);
4930

    
4931

    
4932
--
4933
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4934
--
4935

    
4936
COMMENT ON OPERATOR => (text[], text) IS '
4937
usage: array[''key1'', ...]::text[] => ''value''
4938
';
4939

    
4940

    
4941
--
4942
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4943
--
4944

    
4945
CREATE OPERATOR ?*>= (
4946
    PROCEDURE = is_populated_more_often_than,
4947
    LEFTARG = anyelement,
4948
    RIGHTARG = anyelement
4949
);
4950

    
4951

    
4952
--
4953
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4954
--
4955

    
4956
CREATE OPERATOR ?>= (
4957
    PROCEDURE = is_more_complete_than,
4958
    LEFTARG = anyelement,
4959
    RIGHTARG = anyelement
4960
);
4961

    
4962

    
4963
--
4964
-- Name: @; Type: OPERATOR; Schema: util; Owner: -
4965
--
4966

    
4967
CREATE OPERATOR @ (
4968
    PROCEDURE = contained_within__no_dateline,
4969
    LEFTARG = postgis.geometry,
4970
    RIGHTARG = postgis.geometry
4971
);
4972

    
4973

    
4974
--
4975
-- Name: @; Type: OPERATOR; Schema: util; Owner: -
4976
--
4977

    
4978
CREATE OPERATOR @ (
4979
    PROCEDURE = contained_within__no_dateline,
4980
    LEFTARG = geocoord,
4981
    RIGHTARG = postgis.geometry
4982
);
4983

    
4984

    
4985
--
4986
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4987
--
4988

    
4989
CREATE OPERATOR ||% (
4990
    PROCEDURE = concat_esc,
4991
    LEFTARG = text,
4992
    RIGHTARG = text
4993
);
4994

    
4995

    
4996
--
4997
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4998
--
4999

    
5000
COMMENT ON OPERATOR ||% (text, text) IS '
5001
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
5002
';
5003

    
5004

    
5005
--
5006
-- Name: ~; Type: OPERATOR; Schema: util; Owner: -
5007
--
5008

    
5009
CREATE OPERATOR ~ (
5010
    PROCEDURE = range,
5011
    LEFTARG = numeric,
5012
    RIGHTARG = numeric
5013
);
5014

    
5015

    
5016
--
5017
-- Name: ~@; Type: OPERATOR; Schema: util; Owner: -
5018
--
5019

    
5020
CREATE OPERATOR ~@ (
5021
    PROCEDURE = contained_within_approx,
5022
    LEFTARG = postgis.geography,
5023
    RIGHTARG = postgis.geography
5024
);
5025

    
5026

    
5027
--
5028
-- Name: OPERATOR ~@ (postgis.geography, postgis.geography); Type: COMMENT; Schema: util; Owner: -
5029
--
5030

    
5031
COMMENT ON OPERATOR ~@ (postgis.geography, postgis.geography) IS '
5032
can''t use && because it only compares 2D bounding boxes (which are geometry
5033
objects that do not support geocoordinate wraparound)
5034
';
5035

    
5036

    
5037
--
5038
-- Name: ~@; Type: OPERATOR; Schema: util; Owner: -
5039
--
5040

    
5041
CREATE OPERATOR ~@ (
5042
    PROCEDURE = contained_within_approx,
5043
    LEFTARG = geocoord,
5044
    RIGHTARG = postgis.geography
5045
);
5046

    
5047

    
5048
SET search_path = pg_catalog;
5049

    
5050
--
5051
-- Name: CAST (util.range AS numrange); Type: CAST; Schema: pg_catalog; Owner: -
5052
--
5053

    
5054
CREATE CAST (util.range AS numrange) WITH FUNCTION util.numrange(util.range) AS IMPLICIT;
5055

    
5056

    
5057
SET search_path = util, pg_catalog;
5058

    
5059
--
5060
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
5061
--
5062

    
5063
CREATE TABLE map (
5064
    "from" text NOT NULL,
5065
    "to" text,
5066
    filter text,
5067
    notes text
5068
);
5069

    
5070

    
5071
--
5072
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
5073
--
5074

    
5075

    
5076

    
5077
--
5078
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
5079
--
5080

    
5081

    
5082

    
5083
--
5084
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
5085
--
5086

    
5087
ALTER TABLE ONLY map
5088
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
5089

    
5090

    
5091
--
5092
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
5093
--
5094

    
5095
ALTER TABLE ONLY map
5096
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
5097

    
5098

    
5099
--
5100
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
5101
--
5102

    
5103
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
5104

    
5105

    
5106
--
5107
-- PostgreSQL database dump complete
5108
--
5109

    
(21-21/31)