Project

General

Profile

1
--
2
-- PostgreSQL database dump
3
--
4

    
5
SET statement_timeout = 0;
6
SET lock_timeout = 0;
7
SET client_encoding = 'UTF8';
8
SET standard_conforming_strings = on;
9
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11

    
12
--
13
-- Name: util; Type: SCHEMA; Schema: -; Owner: -
14
--
15

    
16
CREATE SCHEMA util;
17

    
18

    
19
--
20
-- Name: SCHEMA util; Type: COMMENT; Schema: -; Owner: -
21
--
22

    
23
COMMENT ON SCHEMA util IS '
24
IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.
25

    
26
NOTE: SQL-language functions should never be declared STRICT, because this prevents them from being inlined. inlining can create a significant speed improvement (7x+), by avoiding function calls and enabling additional constant folding. avoiding use of STRICT also makes functions *much* easier to troubleshoot, because they won''t mysteriously do nothing if called with only NULL arguments, even when you have added debug-print statements.
27
';
28

    
29

    
30
SET search_path = util, pg_catalog;
31

    
32
--
33
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
34
--
35

    
36
CREATE TYPE col_cast AS (
37
	col_name text,
38
	type regtype
39
);
40

    
41

    
42
--
43
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
44
--
45

    
46
CREATE TYPE col_ref AS (
47
	table_ regclass,
48
	name text
49
);
50

    
51

    
52
--
53
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
54
--
55

    
56
CREATE TYPE compass_dir AS ENUM (
57
    'N',
58
    'E',
59
    'S',
60
    'W'
61
);
62

    
63

    
64
--
65
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
66
--
67

    
68
CREATE TYPE datatype AS ENUM (
69
    'str',
70
    'float'
71
);
72

    
73

    
74
--
75
-- Name: db_item; Type: TYPE; Schema: util; Owner: -
76
--
77

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

    
83

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

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

    
94

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

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

    
103

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

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

    
112

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

    
117
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
118
    LANGUAGE sql IMMUTABLE
119
    AS $_$
120
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
121
$_$;
122

    
123

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

    
128
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
129
    LANGUAGE sql IMMUTABLE
130
    AS $_$
131
SELECT bool_and(value)
132
FROM
133
(VALUES
134
      ($1)
135
    , ($2)
136
    , ($3)
137
    , ($4)
138
    , ($5)
139
)
140
AS v (value)
141
$_$;
142

    
143

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

    
148
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
149
_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.
150
';
151

    
152

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

    
157
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
158
    LANGUAGE sql IMMUTABLE
159
    AS $_$
160
SELECT avg(value)
161
FROM
162
(VALUES
163
      ($1)
164
    , ($2)
165
    , ($3)
166
    , ($4)
167
    , ($5)
168
)
169
AS v (value)
170
$_$;
171

    
172

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

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

    
191

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

    
196
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
197
    LANGUAGE sql IMMUTABLE
198
    AS $_$
199
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
200
FROM
201
(VALUES
202
      ($1)
203
    , ($2/60)
204
    , ($3/60/60)
205
)
206
AS v (value)
207
$_$;
208

    
209

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

    
214
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
215
    LANGUAGE sql IMMUTABLE
216
    AS $_$
217
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
218
$_$;
219

    
220

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

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

    
231

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

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

    
244

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

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

    
255

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

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

    
266

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

    
271
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
272
    LANGUAGE sql IMMUTABLE
273
    AS $_$
274
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
275
$_$;
276

    
277

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

    
282
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
283
    LANGUAGE sql IMMUTABLE
284
    AS $_$
285
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
286
$_$;
287

    
288

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

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

    
299

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

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

    
310

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

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

    
321

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

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

    
336

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

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

    
361

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

    
366
CREATE FUNCTION _max("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
367
    LANGUAGE sql IMMUTABLE
368
    AS $_$
369
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
370
$_$;
371

    
372

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

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

    
411

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

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

    
422

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

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

    
461

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

    
466
CREATE FUNCTION _min("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
467
    LANGUAGE sql IMMUTABLE
468
    AS $_$
469
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
470
$_$;
471

    
472

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

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

    
483

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

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

    
494

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

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

    
505

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

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

    
531

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

    
536
CREATE FUNCTION _or("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
537
    LANGUAGE sql IMMUTABLE
538
    AS $_$
539
SELECT bool_or(value)
540
FROM
541
(VALUES
542
      ($1)
543
    , ($2)
544
    , ($3)
545
    , ($4)
546
    , ($5)
547
)
548
AS v (value)
549
$_$;
550

    
551

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

    
556
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
557
_or() ignores NULL values, while OR combines them with the other values to potentially convert false to NULL. OR should be used with required fields, and _or() with optional fields.
558
';
559

    
560

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

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

    
571

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

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

    
582

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

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

    
600

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

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

    
609

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

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

    
620

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

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

    
637

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

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

    
648

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

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

    
659

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

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

    
668

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

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

    
679

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

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

    
690

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

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

    
701

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

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

    
710

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

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

    
721

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

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

    
735

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

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

    
752

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

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

    
763

    
764
--
765
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
766
--
767

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

    
779

    
780
--
781
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
782
--
783

    
784
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
785
allows casting to an arbitrary type without eval()
786

    
787
usage:
788
SELECT util.cast(''value'', NULL::integer);
789

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

    
794
ret_type_null: NULL::ret_type
795
';
796

    
797

    
798
--
799
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
800
--
801

    
802
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
803
    LANGUAGE sql STABLE
804
    AS $_$
805
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
806
$_$;
807

    
808

    
809
--
810
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
811
--
812

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

    
824

    
825
--
826
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
827
--
828

    
829
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
830
idempotent
831
';
832

    
833

    
834
--
835
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
836
--
837

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

    
847

    
848
--
849
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
850
--
851

    
852
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
853
uses:
854
* coalescing array elements or rows together
855
* forcing evaluation of all values of a COALESCE()
856
';
857

    
858

    
859
--
860
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
861
--
862

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

    
874

    
875
--
876
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
877
--
878

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

    
898

    
899
--
900
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
901
--
902

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

    
921

    
922
--
923
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
924
--
925

    
926
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
927
    LANGUAGE sql STABLE
928
    AS $_$
929
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
930
$_$;
931

    
932

    
933
--
934
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
935
--
936

    
937
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
938
ret_type_null: NULL::ret_type
939
';
940

    
941

    
942
--
943
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
944
--
945

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

    
957

    
958
--
959
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
960
--
961

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

    
974

    
975
--
976
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
977
--
978

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

    
988

    
989
--
990
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
991
--
992

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

    
1001

    
1002
--
1003
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
1004
--
1005

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

    
1024

    
1025
--
1026
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
1027
--
1028

    
1029
CREATE FUNCTION comment(element oid) RETURNS text
1030
    LANGUAGE sql STABLE
1031
    AS $_$
1032
SELECT description FROM pg_description WHERE objoid = $1
1033
$_$;
1034

    
1035

    
1036
--
1037
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
1038
--
1039

    
1040
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
1041
    LANGUAGE sql IMMUTABLE
1042
    AS $_$
1043
SELECT util.esc_name__append($2, $1)
1044
$_$;
1045

    
1046

    
1047
--
1048
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
1049
--
1050

    
1051
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
1052
    LANGUAGE sql IMMUTABLE
1053
    AS $_$
1054
SELECT position($1 in $2) > 0 /*1-based offset*/
1055
$_$;
1056

    
1057

    
1058
--
1059
-- Name: copy(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1060
--
1061

    
1062
CREATE FUNCTION copy(from_ regclass, to_ text) RETURNS void
1063
    LANGUAGE sql
1064
    AS $_$
1065
SELECT util.copy_struct($1, $2);
1066
SELECT util.copy_data($1, $2);
1067
$_$;
1068

    
1069

    
1070
--
1071
-- Name: copy_data(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1072
--
1073

    
1074
CREATE FUNCTION copy_data(from_ regclass, to_ regclass) RETURNS void
1075
    LANGUAGE sql
1076
    AS $_$
1077
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT * FROM $$||$1)
1078
$_$;
1079

    
1080

    
1081
--
1082
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1083
--
1084

    
1085
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1086
    LANGUAGE sql
1087
    AS $_$
1088
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1089
$_$;
1090

    
1091

    
1092
--
1093
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1094
--
1095

    
1096
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1097
    LANGUAGE sql
1098
    AS $_$
1099
SELECT util.materialize_view($2, $1)
1100
$_$;
1101

    
1102

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

    
1107
CREATE FUNCTION create_if_not_exists(sql text, relation text DEFAULT NULL::text) RETURNS void
1108
    LANGUAGE plpgsql
1109
    AS $$
1110
BEGIN
1111
	/* always generate standard exception if exists, even if table definition
1112
	would be invalid (which generates a variety of exceptions) */
1113
	IF util.relation_exists(relation) THEN
1114
		PERFORM util.raise('NOTICE', relation||' already exists, skipping');
1115
		RAISE duplicate_table;
1116
	END IF;
1117
	PERFORM util.eval(sql);
1118
EXCEPTION
1119
WHEN   duplicate_table
1120
	OR duplicate_object -- eg. constraint
1121
	OR duplicate_column
1122
	OR duplicate_function
1123
THEN NULL;
1124
WHEN invalid_table_definition THEN
1125
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1126
	ELSE RAISE;
1127
	END IF;
1128
END;
1129
$$;
1130

    
1131

    
1132
--
1133
-- Name: FUNCTION create_if_not_exists(sql text, relation text); Type: COMMENT; Schema: util; Owner: -
1134
--
1135

    
1136
COMMENT ON FUNCTION create_if_not_exists(sql text, relation text) IS '
1137
idempotent
1138
';
1139

    
1140

    
1141
--
1142
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1143
--
1144

    
1145
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1146
    LANGUAGE sql STABLE
1147
    AS $$
1148
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1149
$$;
1150

    
1151

    
1152
--
1153
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1154
--
1155

    
1156
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1157
    LANGUAGE sql IMMUTABLE
1158
    AS $_$
1159
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1160
$_$;
1161

    
1162

    
1163
--
1164
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1165
--
1166

    
1167
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1168
    LANGUAGE sql IMMUTABLE
1169
    AS $_$
1170
SELECT util.debug_print_value('returns: ', $1, $2);
1171
SELECT $1;
1172
$_$;
1173

    
1174

    
1175
--
1176
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1177
--
1178

    
1179
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1180
    LANGUAGE sql IMMUTABLE
1181
    AS $_$
1182
/* newline before so the query starts at the beginning of the line.
1183
newline after to visually separate queries from one another. */
1184
SELECT util.raise('NOTICE', $$
1185
$$||util.runnable_sql($1)||$$
1186
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1187
$_$;
1188

    
1189

    
1190
--
1191
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1192
--
1193

    
1194
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1195
    LANGUAGE sql IMMUTABLE
1196
    AS $_$
1197
SELECT util.raise('NOTICE', concat($1,
1198
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1199
$$)
1200
$_$;
1201

    
1202

    
1203
--
1204
-- Name: debug_print_var(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1205
--
1206

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

    
1216

    
1217
--
1218
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1219
--
1220

    
1221
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1222
    LANGUAGE sql STABLE
1223
    AS $_$
1224
SELECT util.eval2set($$
1225
SELECT col
1226
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1227
LEFT JOIN $$||$2||$$ ON "to" = col
1228
WHERE "from" IS NULL
1229
$$, NULL::text)
1230
$_$;
1231

    
1232

    
1233
--
1234
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1235
--
1236

    
1237
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1238
gets table_''s derived columns (all the columns not in the names table)
1239
';
1240

    
1241

    
1242
--
1243
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1244
--
1245

    
1246
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1247
    LANGUAGE sql
1248
    AS $_$
1249
-- create a diff when the # of copies of a row differs between the tables
1250
SELECT util.to_freq($1);
1251
SELECT util.to_freq($2);
1252
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1253

    
1254
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1255
$_$;
1256

    
1257

    
1258
--
1259
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1260
--
1261

    
1262
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1263
usage:
1264
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1265

    
1266
col_type_null (*required*): NULL::shared_base_type
1267
';
1268

    
1269

    
1270
--
1271
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1272
--
1273

    
1274
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
1275
    LANGUAGE plpgsql
1276
    SET search_path TO pg_temp
1277
    AS $_$
1278
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1279
changes of search_path (schema elements are bound at inline time rather than
1280
runtime) */
1281
/* function option search_path is needed to limit the effects of
1282
`SET LOCAL search_path` to the current function */
1283
BEGIN
1284
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1285
	
1286
	PERFORM util.mk_keys_func(pg_typeof($3));
1287
	RETURN QUERY
1288
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1289
$$/* need to explicitly cast each side to the return type because this does not
1290
happen automatically even when an implicit cast is available */
1291
  left_::$$||util.typeof($3)||$$
1292
, right_::$$||util.typeof($3)
1293
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1294
the *same* base type, *even though* this is optional when using a custom %== */
1295
, util._if($4, $$true/*= CROSS JOIN*/$$,
1296
$$ left_::$$||util.typeof($3)||$$
1297
%== right_::$$||util.typeof($3)||$$
1298
	-- refer to EXPLAIN output for expansion of %==$$
1299
)
1300
,     $$         left_::$$||util.typeof($3)||$$
1301
IS DISTINCT FROM right_::$$||util.typeof($3)
1302
), $3)
1303
	;
1304
END;
1305
$_$;
1306

    
1307

    
1308
--
1309
-- 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: -
1310
--
1311

    
1312
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1313
col_type_null (*required*): NULL::col_type
1314
single_row: whether the tables consist of a single row, which should be
1315
	displayed side-by-side
1316

    
1317
to match up rows using a subset of the columns, create a custom keys() function
1318
which returns this subset as a record:
1319
-- note that OUT parameters for the returned fields are *not* needed
1320
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1321
  RETURNS record AS
1322
$BODY$
1323
SELECT ($1.key_field_0, $1.key_field_1)
1324
$BODY$
1325
  LANGUAGE sql IMMUTABLE
1326
  COST 100;
1327

    
1328

    
1329
to run EXPLAIN on the FULL JOIN query:
1330
# run this function
1331
# look for a NOTICE containing the expanded query that it ran
1332
# run EXPLAIN on this expanded query
1333
';
1334

    
1335

    
1336
--
1337
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1338
--
1339

    
1340
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
1341
    LANGUAGE sql
1342
    AS $_$
1343
SELECT * FROM util.diff($1::text, $2::text, $3,
1344
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1345
$_$;
1346

    
1347

    
1348
--
1349
-- 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: -
1350
--
1351

    
1352
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1353
helper function used by diff(regclass, regclass)
1354

    
1355
usage:
1356
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1357

    
1358
col_type_null (*required*): NULL::shared_base_type
1359
';
1360

    
1361

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

    
1366
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1367
    LANGUAGE sql
1368
    AS $_$
1369
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1370
$_$;
1371

    
1372

    
1373
--
1374
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1375
--
1376

    
1377
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1378
idempotent
1379
';
1380

    
1381

    
1382
--
1383
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1384
--
1385

    
1386
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1387
    LANGUAGE sql
1388
    AS $_$
1389
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1390
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1391
$_$;
1392

    
1393

    
1394
--
1395
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1396
--
1397

    
1398
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1399
idempotent
1400
';
1401

    
1402

    
1403
--
1404
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1405
--
1406

    
1407
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1408
    LANGUAGE sql
1409
    AS $_$
1410
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1411
SELECT NULL::void; -- don't fold away functions called in previous query
1412
$_$;
1413

    
1414

    
1415
--
1416
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1417
--
1418

    
1419
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1420
idempotent
1421
';
1422

    
1423

    
1424
--
1425
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1426
--
1427

    
1428
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1429
    LANGUAGE sql
1430
    AS $_$
1431
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1432
included in the debug SQL */
1433
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1434
$_$;
1435

    
1436

    
1437
--
1438
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1439
--
1440

    
1441
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1442
    LANGUAGE sql
1443
    AS $_$
1444
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1445
||util._if($3, $$ CASCADE$$, ''::text))
1446
$_$;
1447

    
1448

    
1449
--
1450
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1451
--
1452

    
1453
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1454
idempotent
1455
';
1456

    
1457

    
1458
--
1459
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1460
--
1461

    
1462
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1463
    LANGUAGE sql
1464
    AS $_$
1465
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1466
$_$;
1467

    
1468

    
1469
--
1470
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1471
--
1472

    
1473
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1474
    LANGUAGE sql
1475
    AS $_$
1476
SELECT util.debug_print_func_call(util.quote_func_call(
1477
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1478
util.quote_typed($3)))
1479
;
1480
SELECT util.drop_relation(relation, $3)
1481
FROM util.show_relations_like($1, $2) relation
1482
;
1483
SELECT NULL::void; -- don't fold away functions called in previous query
1484
$_$;
1485

    
1486

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

    
1491
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1492
    LANGUAGE sql
1493
    AS $_$
1494
SELECT util.drop_relation('TABLE', $1, $2)
1495
$_$;
1496

    
1497

    
1498
--
1499
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1500
--
1501

    
1502
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1503
idempotent
1504
';
1505

    
1506

    
1507
--
1508
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1509
--
1510

    
1511
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1512
    LANGUAGE sql
1513
    AS $_$
1514
SELECT util.drop_relation('VIEW', $1, $2)
1515
$_$;
1516

    
1517

    
1518
--
1519
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1520
--
1521

    
1522
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1523
idempotent
1524
';
1525

    
1526

    
1527
--
1528
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1529
--
1530

    
1531
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1532
    LANGUAGE sql IMMUTABLE
1533
    AS $_$
1534
SELECT util.array_fill($1, 0)
1535
$_$;
1536

    
1537

    
1538
--
1539
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1540
--
1541

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

    
1546

    
1547
--
1548
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1549
--
1550

    
1551
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1552
    LANGUAGE sql IMMUTABLE
1553
    AS $_$
1554
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1555
$_$;
1556

    
1557

    
1558
--
1559
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1560
--
1561

    
1562
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1563
    LANGUAGE sql IMMUTABLE
1564
    AS $_$
1565
SELECT regexp_replace($2, '("?)$', $1||'\1')
1566
$_$;
1567

    
1568

    
1569
--
1570
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1571
--
1572

    
1573
CREATE FUNCTION eval(queries text[]) RETURNS void
1574
    LANGUAGE sql
1575
    AS $_$
1576
SELECT util.eval(query) FROM unnest($1) query;
1577
SELECT NULL::void; -- don't fold away functions called in previous query
1578
$_$;
1579

    
1580

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

    
1585
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1586
    LANGUAGE plpgsql
1587
    AS $$
1588
BEGIN
1589
	sql = util.view_def_to_orig(sql); -- restore user's intent
1590
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1591
	EXECUTE sql;
1592
END;
1593
$$;
1594

    
1595

    
1596
--
1597
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1598
--
1599

    
1600
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1601
    LANGUAGE plpgsql
1602
    AS $$
1603
BEGIN
1604
	PERFORM util.debug_print_sql(sql);
1605
	RETURN QUERY EXECUTE sql;
1606
END;
1607
$$;
1608

    
1609

    
1610
--
1611
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1612
--
1613

    
1614
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1615
col_type_null (*required*): NULL::col_type
1616
';
1617

    
1618

    
1619
--
1620
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1621
--
1622

    
1623
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1624
    LANGUAGE plpgsql
1625
    AS $$
1626
BEGIN
1627
	PERFORM util.debug_print_sql(sql);
1628
	RETURN QUERY EXECUTE sql;
1629
END;
1630
$$;
1631

    
1632

    
1633
--
1634
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1635
--
1636

    
1637
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1638
    LANGUAGE plpgsql
1639
    AS $$
1640
BEGIN
1641
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1642
	RETURN QUERY EXECUTE sql;
1643
END;
1644
$$;
1645

    
1646

    
1647
--
1648
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1649
--
1650

    
1651
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1652
    LANGUAGE plpgsql STABLE
1653
    AS $$
1654
DECLARE
1655
	ret_val ret_type_null%TYPE;
1656
BEGIN
1657
	PERFORM util.debug_print_sql(sql);
1658
	EXECUTE sql INTO STRICT ret_val;
1659
	RETURN ret_val;
1660
END;
1661
$$;
1662

    
1663

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

    
1668
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1669
ret_type_null: NULL::ret_type
1670
';
1671

    
1672

    
1673
--
1674
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1675
--
1676

    
1677
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1678
    LANGUAGE sql
1679
    AS $_$
1680
SELECT util.eval2val($$SELECT $$||$1, $2)
1681
$_$;
1682

    
1683

    
1684
--
1685
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1686
--
1687

    
1688
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1689
ret_type_null: NULL::ret_type
1690
';
1691

    
1692

    
1693
--
1694
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1695
--
1696

    
1697
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1698
    LANGUAGE sql
1699
    AS $_$
1700
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1701
$_$;
1702

    
1703

    
1704
--
1705
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1706
--
1707

    
1708
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1709
sql: can be NULL, which will be passed through
1710
ret_type_null: NULL::ret_type
1711
';
1712

    
1713

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

    
1718
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1719
    LANGUAGE sql STABLE
1720
    AS $_$
1721
SELECT col_name
1722
FROM unnest($2) s (col_name)
1723
WHERE util.col_exists(($1, col_name))
1724
$_$;
1725

    
1726

    
1727
--
1728
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1729
--
1730

    
1731
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1732
    LANGUAGE sql
1733
    SET client_min_messages TO 'error'
1734
    AS $_$
1735
/* `client_min_messages = ERROR`: EXPLAIN apparently runs IMMUTABLE functions in
1736
the query, so this prevents displaying any log messages printed by them */
1737
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1738
$_$;
1739

    
1740

    
1741
--
1742
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1743
--
1744

    
1745
CREATE FUNCTION explain2notice(sql text) RETURNS void
1746
    LANGUAGE sql
1747
    AS $_$
1748
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1749
$_$;
1750

    
1751

    
1752
--
1753
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1754
--
1755

    
1756
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1757
    LANGUAGE sql
1758
    AS $_$
1759
-- newline before and after to visually separate it from other debug info
1760
SELECT COALESCE($$
1761
EXPLAIN:
1762
$$||util.fold_explain_msg(util.explain2str($1))||$$
1763
$$, '')
1764
$_$;
1765

    
1766

    
1767
--
1768
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1769
--
1770

    
1771
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1772
    LANGUAGE plpgsql
1773
    AS $$
1774
BEGIN
1775
	RETURN util.explain2notice_msg(sql);
1776
EXCEPTION
1777
WHEN   syntax_error
1778
	OR invalid_cursor_definition -- "cannot open multi-query plan as cursor"
1779
	THEN RETURN NULL; -- non-explainable query
1780
	/* don't use util.is_explainable() because the list provided by Postgres
1781
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1782
	excludes some query types that are in fact EXPLAIN-able */
1783
END;
1784
$$;
1785

    
1786

    
1787
--
1788
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1789
--
1790

    
1791
CREATE FUNCTION explain2str(sql text) RETURNS text
1792
    LANGUAGE sql
1793
    AS $_$
1794
SELECT util.join_strs(explain, $$
1795
$$) FROM util.explain($1)
1796
$_$;
1797

    
1798

    
1799
SET default_tablespace = '';
1800

    
1801
SET default_with_oids = false;
1802

    
1803
--
1804
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1805
--
1806

    
1807
CREATE TABLE explain (
1808
    line text NOT NULL
1809
);
1810

    
1811

    
1812
--
1813
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1814
--
1815

    
1816
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1817
    LANGUAGE sql
1818
    AS $_$
1819
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1820
$$||quote_nullable($1)||$$
1821
)$$)
1822
$_$;
1823

    
1824

    
1825
--
1826
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1827
--
1828

    
1829
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1830
usage:
1831
PERFORM util.explain2table($$
1832
query
1833
$$);
1834
';
1835

    
1836

    
1837
--
1838
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1839
--
1840

    
1841
CREATE FUNCTION first_word(str text) RETURNS text
1842
    LANGUAGE sql IMMUTABLE
1843
    AS $_$
1844
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1845
$_$;
1846

    
1847

    
1848
--
1849
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1850
--
1851

    
1852
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1853
    LANGUAGE sql IMMUTABLE
1854
    AS $_$
1855
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1856
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1857
) END
1858
$_$;
1859

    
1860

    
1861
--
1862
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1863
--
1864

    
1865
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1866
ensures that an array will always have proper non-NULL dimensions
1867
';
1868

    
1869

    
1870
--
1871
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
1872
--
1873

    
1874
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1875
    LANGUAGE sql IMMUTABLE
1876
    AS $_$
1877
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1878
$_$;
1879

    
1880

    
1881
--
1882
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1883
--
1884

    
1885
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1886
    LANGUAGE plpgsql STRICT
1887
    AS $_$
1888
DECLARE
1889
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1890
$$||query;
1891
BEGIN
1892
	EXECUTE mk_view;
1893
EXCEPTION
1894
WHEN invalid_table_definition THEN
1895
	IF SQLERRM = 'cannot drop columns from view'
1896
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1897
	THEN
1898
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1899
		EXECUTE mk_view;
1900
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1901
	END IF;
1902
END;
1903
$_$;
1904

    
1905

    
1906
--
1907
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1908
--
1909

    
1910
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1911
idempotent
1912
';
1913

    
1914

    
1915
--
1916
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1917
--
1918

    
1919
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1920
    LANGUAGE sql STABLE
1921
    AS $_$
1922
SELECT util.eval2val(
1923
$$SELECT NOT EXISTS( -- there is no row that is != 1
1924
	SELECT NULL
1925
	FROM $$||$1||$$
1926
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1927
	LIMIT 1
1928
)
1929
$$, NULL::boolean)
1930
$_$;
1931

    
1932

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

    
1937
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1938
    LANGUAGE sql STABLE
1939
    AS $_$
1940
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1941
$_$;
1942

    
1943

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

    
1948
CREATE FUNCTION grants_users() RETURNS SETOF text
1949
    LANGUAGE sql IMMUTABLE
1950
    AS $$
1951
VALUES ('bien_read'), ('public_')
1952
$$;
1953

    
1954

    
1955
--
1956
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1957
--
1958

    
1959
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1960
    LANGUAGE sql IMMUTABLE
1961
    AS $_$
1962
SELECT substring($2 for length($1)) = $1
1963
$_$;
1964

    
1965

    
1966
--
1967
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1968
--
1969

    
1970
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1971
    LANGUAGE sql STABLE
1972
    AS $_$
1973
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1974
$_$;
1975

    
1976

    
1977
--
1978
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1979
--
1980

    
1981
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1982
    LANGUAGE sql IMMUTABLE
1983
    AS $_$
1984
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1985
$_$;
1986

    
1987

    
1988
--
1989
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1990
--
1991

    
1992
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1993
avoids repeating the same value for each key
1994
';
1995

    
1996

    
1997
--
1998
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1999
--
2000

    
2001
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
2002
    LANGUAGE sql IMMUTABLE
2003
    AS $_$
2004
SELECT COALESCE($1, $2)
2005
$_$;
2006

    
2007

    
2008
--
2009
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
2010
--
2011

    
2012
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
2013
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
2014
';
2015

    
2016

    
2017
--
2018
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
2019
--
2020

    
2021
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
2022
    LANGUAGE sql IMMUTABLE
2023
    AS $_$
2024
SELECT elem FROM unnest($1) elem ORDER BY row_number() OVER () DESC
2025
$_$;
2026

    
2027

    
2028
--
2029
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2030
--
2031

    
2032
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
2033
    LANGUAGE sql
2034
    AS $_$
2035
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
2036
$_$;
2037

    
2038

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

    
2043
CREATE FUNCTION is_castable(value text, ret_type_null anyelement) RETURNS boolean
2044
    LANGUAGE plpgsql IMMUTABLE
2045
    AS $$
2046
BEGIN
2047
	PERFORM util.cast(value, ret_type_null);
2048
	-- must happen *after* cast check, because NULL is not valid for some types
2049
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
2050
	RETURN true;
2051
EXCEPTION
2052
WHEN   data_exception
2053
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
2054
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
2055
	THEN
2056
	RETURN false;
2057
END;
2058
$$;
2059

    
2060

    
2061
--
2062
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
2063
--
2064

    
2065
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
2066
passes NULL through. however, if NULL is not valid for the type, false will be
2067
returned instead.
2068

    
2069
ret_type_null: NULL::ret_type
2070
';
2071

    
2072

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

    
2077
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
2078
    LANGUAGE sql STABLE
2079
    AS $_$
2080
SELECT COALESCE(util.col_comment($1) LIKE '
2081
constant
2082
%', false)
2083
$_$;
2084

    
2085

    
2086
--
2087
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2088
--
2089

    
2090
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
2091
    LANGUAGE sql IMMUTABLE
2092
    AS $_$
2093
SELECT util.array_length($1) = 0
2094
$_$;
2095

    
2096

    
2097
--
2098
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
2099
--
2100

    
2101
CREATE FUNCTION is_explain(sql text) RETURNS boolean
2102
    LANGUAGE sql IMMUTABLE
2103
    AS $_$
2104
SELECT upper(util.first_word($1)) = 'EXPLAIN'
2105
$_$;
2106

    
2107

    
2108
--
2109
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
2110
--
2111

    
2112
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
2113
    LANGUAGE sql IMMUTABLE
2114
    AS $_$
2115
SELECT upper(util.first_word($1)) = ANY(
2116
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
2117
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
2118
)
2119
$_$;
2120

    
2121

    
2122
--
2123
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2124
--
2125

    
2126
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
2127
    LANGUAGE sql IMMUTABLE
2128
    AS $_$
2129
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2130
$_$;
2131

    
2132

    
2133
--
2134
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2135
--
2136

    
2137
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2138
    LANGUAGE sql IMMUTABLE
2139
    AS $_$
2140
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2141
$_$;
2142

    
2143

    
2144
--
2145
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
2146
--
2147

    
2148
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2149
    LANGUAGE sql IMMUTABLE
2150
    AS $_$
2151
SELECT upper(util.first_word($1)) = 'SET'
2152
$_$;
2153

    
2154

    
2155
--
2156
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
2157
--
2158

    
2159
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2160
    LANGUAGE sql STABLE
2161
    AS $_$
2162
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2163
$_$;
2164

    
2165

    
2166
--
2167
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2168
--
2169

    
2170
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2171
    LANGUAGE sql STABLE
2172
    AS $_$
2173
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2174
$_$;
2175

    
2176

    
2177
--
2178
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2179
--
2180

    
2181
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2182
    LANGUAGE sql IMMUTABLE STRICT
2183
    AS $_$
2184
SELECT $1 || $3 || $2
2185
$_$;
2186

    
2187

    
2188
--
2189
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2190
--
2191

    
2192
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2193
must be declared STRICT to use the special handling of STRICT aggregating functions
2194
';
2195

    
2196

    
2197
--
2198
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2199
--
2200

    
2201
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2202
    LANGUAGE sql IMMUTABLE
2203
    AS $_$
2204
SELECT $1 -- compare on the entire value
2205
$_$;
2206

    
2207

    
2208
--
2209
-- Name: keys_eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2210
--
2211

    
2212
CREATE FUNCTION keys_eq(left_ anyelement, right_ anyelement) RETURNS boolean
2213
    LANGUAGE sql STABLE
2214
    AS $_$
2215
SELECT keys($1) = keys($2)
2216
$_$;
2217

    
2218

    
2219
--
2220
-- Name: FUNCTION keys_eq(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
2221
--
2222

    
2223
COMMENT ON FUNCTION keys_eq(left_ anyelement, right_ anyelement) IS '
2224
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**)
2225
';
2226

    
2227

    
2228
--
2229
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2230
--
2231

    
2232
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2233
    LANGUAGE sql IMMUTABLE
2234
    AS $_$
2235
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2236
$_$;
2237

    
2238

    
2239
--
2240
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2241
--
2242

    
2243
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2244
    LANGUAGE plpgsql
2245
    AS $$
2246
DECLARE
2247
	errors_ct integer = 0;
2248
	loop_var loop_type_null%TYPE;
2249
BEGIN
2250
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2251
	LOOP
2252
		BEGIN
2253
			EXECUTE loop_body_sql USING loop_var;
2254
		EXCEPTION
2255
		WHEN OTHERS THEN
2256
			errors_ct = errors_ct+1;
2257
			PERFORM util.raise_error_warning(SQLERRM);
2258
		END;
2259
	END LOOP;
2260
	IF errors_ct > 0 THEN
2261
		-- can't raise exception because this would roll back the transaction
2262
		PERFORM util.raise_error_warning('there were '||errors_ct
2263
			||' errors: see the WARNINGs for details');
2264
	END IF;
2265
END;
2266
$$;
2267

    
2268

    
2269
--
2270
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
2271
--
2272

    
2273
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2274
    LANGUAGE sql IMMUTABLE
2275
    AS $_$
2276
SELECT ltrim($1, $$
2277
$$)
2278
$_$;
2279

    
2280

    
2281
--
2282
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2283
--
2284

    
2285
CREATE FUNCTION map_filter_insert() RETURNS trigger
2286
    LANGUAGE plpgsql
2287
    AS $$
2288
BEGIN
2289
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2290
	RETURN new;
2291
END;
2292
$$;
2293

    
2294

    
2295
--
2296
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2297
--
2298

    
2299
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2300
    LANGUAGE plpgsql STABLE STRICT
2301
    AS $_$
2302
DECLARE
2303
    value text;
2304
BEGIN
2305
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2306
        INTO value USING key;
2307
    RETURN value;
2308
END;
2309
$_$;
2310

    
2311

    
2312
--
2313
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2314
--
2315

    
2316
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2317
    LANGUAGE sql IMMUTABLE
2318
    AS $_$
2319
SELECT util._map(util.nulls_map($1), $2)
2320
$_$;
2321

    
2322

    
2323
--
2324
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2325
--
2326

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

    
2330
[1] inlining of function calls, which is different from constant folding
2331
[2] _map()''s profiling query
2332
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2333
and map_nulls()''s profiling query
2334
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2335
both take ~920 ms.
2336
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.
2337
';
2338

    
2339

    
2340
--
2341
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2342
--
2343

    
2344
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2345
    LANGUAGE plpgsql STABLE STRICT
2346
    AS $_$
2347
BEGIN
2348
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2349
END;
2350
$_$;
2351

    
2352

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

    
2357
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2358
    LANGUAGE sql
2359
    AS $_$
2360
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2361
$$||util.ltrim_nl($2));
2362
-- make sure the created table has the correct estimated row count
2363
SELECT util.analyze_($1);
2364

    
2365
SELECT util.append_comment($1, '
2366
contents generated from:
2367
'||util.ltrim_nl(util.runnable_sql($2))||';
2368
');
2369
$_$;
2370

    
2371

    
2372
--
2373
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2374
--
2375

    
2376
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2377
idempotent
2378
';
2379

    
2380

    
2381
--
2382
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2383
--
2384

    
2385
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2386
    LANGUAGE sql
2387
    AS $_$
2388
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2389
$_$;
2390

    
2391

    
2392
--
2393
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2394
--
2395

    
2396
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2397
idempotent
2398
';
2399

    
2400

    
2401
--
2402
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2403
--
2404

    
2405
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2406
    LANGUAGE sql
2407
    AS $_$
2408
SELECT util.create_if_not_exists($$
2409
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2410
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2411
||quote_literal($2)||$$;
2412
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2413
constant
2414
';
2415
$$)
2416
$_$;
2417

    
2418

    
2419
--
2420
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2421
--
2422

    
2423
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2424
idempotent
2425
';
2426

    
2427

    
2428
--
2429
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2430
--
2431

    
2432
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2433
    LANGUAGE plpgsql STRICT
2434
    AS $_$
2435
DECLARE
2436
    type regtype = util.typeof(expr, col.table_::text::regtype);
2437
    col_name_sql text = quote_ident(col.name);
2438
BEGIN
2439
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2440
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2441
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2442
$$||expr||$$;
2443
$$);
2444
END;
2445
$_$;
2446

    
2447

    
2448
--
2449
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2450
--
2451

    
2452
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2453
idempotent
2454
';
2455

    
2456

    
2457
--
2458
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2459
--
2460

    
2461
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
2462
    LANGUAGE sql IMMUTABLE
2463
    AS $_$
2464
SELECT
2465
$$SELECT
2466
$$||$3||$$
2467
FROM      $$||$1||$$ left_
2468
FULL JOIN $$||$2||$$ right_
2469
ON $$||$4||$$
2470
WHERE $$||$5||$$
2471
ORDER BY left_, right_
2472
$$
2473
$_$;
2474

    
2475

    
2476
--
2477
-- Name: mk_drop_from_create(text); Type: FUNCTION; Schema: util; Owner: -
2478
--
2479

    
2480
CREATE FUNCTION mk_drop_from_create(create_cmd text) RETURNS text
2481
    LANGUAGE sql IMMUTABLE
2482
    AS $_$
2483
SELECT $$DROP $$||(util.regexp_match($1,
2484
-- match first CREATE, *if* no DROP came before it
2485
'(?m)\A(?:^(?!DROP\y).*\n)*?^CREATE(?: OR REPLACE)? ((?:)??[[:upper:]]+ .*?)(?: AS(?: (?:SELECT\y.*)?)?)?$'
2486
	/* (?:)?? makes the surrounding () group non-greedy, so that (?: AS ?)?
2487
	works properly (due to nonstandard Postgres regexp behavior:
2488
	http://www.postgresql.org/docs/9.3/static/functions-matching.html#POSIX-MATCHING-RULES) */
2489
))[1]||$$;$$
2490
$_$;
2491

    
2492

    
2493
--
2494
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2495
--
2496

    
2497
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2498
    LANGUAGE sql
2499
    AS $_$
2500
-- keys()
2501
SELECT util.mk_keys_func($1, ARRAY(
2502
SELECT col FROM util.typed_cols($1) col
2503
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2504
));
2505

    
2506
-- values_()
2507
SELECT util.mk_keys_func($1, COALESCE(
2508
	NULLIF(ARRAY(
2509
	SELECT col FROM util.typed_cols($1) col
2510
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2511
	), ARRAY[]::util.col_cast[])
2512
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2513
, 'values_');
2514
$_$;
2515

    
2516

    
2517
--
2518
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2519
--
2520

    
2521
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2522
    LANGUAGE sql
2523
    AS $_$
2524
SELECT util.create_if_not_exists($$
2525
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2526
($$||util.mk_typed_cols_list($2)||$$);
2527
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2528
autogenerated
2529
';
2530
$$);
2531

    
2532
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2533
$_$;
2534

    
2535

    
2536
--
2537
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2538
--
2539

    
2540
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2541
    LANGUAGE sql
2542
    AS $_$
2543
SELECT util.create_if_not_exists($$
2544
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2545
||util.qual_name($1)||$$)
2546
  RETURNS $$||util.qual_name($2)||$$ AS
2547
$BODY1$
2548
SELECT ROW($$||
2549
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2550
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2551
$BODY1$
2552
  LANGUAGE sql IMMUTABLE
2553
  COST 100;
2554
$$);
2555
$_$;
2556

    
2557

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

    
2562
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2563
    LANGUAGE sql
2564
    AS $_$
2565
SELECT util.create_if_not_exists($$
2566
CREATE TABLE $$||$1||$$
2567
(
2568
    LIKE util.map INCLUDING ALL
2569
);
2570

    
2571
CREATE TRIGGER map_filter_insert
2572
  BEFORE INSERT
2573
  ON $$||$1||$$
2574
  FOR EACH ROW
2575
  EXECUTE PROCEDURE util.map_filter_insert();
2576
$$)
2577
$_$;
2578

    
2579

    
2580
--
2581
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2582
--
2583

    
2584
CREATE FUNCTION mk_not_null(text) RETURNS text
2585
    LANGUAGE sql IMMUTABLE
2586
    AS $_$
2587
SELECT COALESCE($1, '<NULL>')
2588
$_$;
2589

    
2590

    
2591
--
2592
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2593
--
2594

    
2595
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2596
    LANGUAGE sql IMMUTABLE
2597
    AS $_$
2598
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2599
util.qual_name((unnest).type), ''), '')
2600
FROM unnest($1)
2601
$_$;
2602

    
2603

    
2604
--
2605
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2606
--
2607

    
2608
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2609
    LANGUAGE sql IMMUTABLE
2610
    AS $_$
2611
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2612
$_$;
2613

    
2614

    
2615
--
2616
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2617
--
2618

    
2619
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2620
auto-appends util to the search_path to enable use of util operators
2621
';
2622

    
2623

    
2624
--
2625
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2626
--
2627

    
2628
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2629
    LANGUAGE sql STABLE
2630
    AS $_$
2631
SELECT COALESCE($$COMMENT ON $$||util.relation_type($1)||$$ $$||$1||$$ IS $$
2632
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2633
$_$;
2634

    
2635

    
2636
--
2637
-- Name: mk_set_relation_metadata(regclass); Type: FUNCTION; Schema: util; Owner: -
2638
--
2639

    
2640
CREATE FUNCTION mk_set_relation_metadata(relation regclass) RETURNS text
2641
    LANGUAGE sql STABLE
2642
    AS $_$
2643
SELECT util.show_grants_for($1)
2644
||util.show_set_comment($1)||$$
2645
$$
2646
$_$;
2647

    
2648

    
2649
--
2650
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2651
--
2652

    
2653
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2654
    LANGUAGE sql IMMUTABLE
2655
    AS $_$
2656
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2657
$_$;
2658

    
2659

    
2660
--
2661
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2662
--
2663

    
2664
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2665
    LANGUAGE sql IMMUTABLE
2666
    AS $_$
2667
/* debug_print_return_value() needed because this function is used with EXECUTE
2668
rather than util.eval() (in order to affect the calling function), so the
2669
search_path would not otherwise be printed */
2670
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2671
||$$ search_path TO $$||$1
2672
$_$;
2673

    
2674

    
2675
--
2676
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2677
--
2678

    
2679
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2680
    LANGUAGE sql
2681
    AS $_$
2682
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2683
$_$;
2684

    
2685

    
2686
--
2687
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2688
--
2689

    
2690
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2691
idempotent
2692
';
2693

    
2694

    
2695
--
2696
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2697
--
2698

    
2699
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2700
    LANGUAGE plpgsql STRICT
2701
    AS $_$
2702
DECLARE
2703
	view_qual_name text = util.qual_name(view_);
2704
BEGIN
2705
	EXECUTE $$
2706
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2707
  RETURNS SETOF $$||view_||$$ AS
2708
$BODY1$
2709
SELECT * FROM $$||view_qual_name||$$
2710
ORDER BY sort_col
2711
LIMIT $1 OFFSET $2
2712
$BODY1$
2713
  LANGUAGE sql STABLE
2714
  COST 100
2715
  ROWS 1000
2716
$$;
2717
	
2718
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2719
END;
2720
$_$;
2721

    
2722

    
2723
--
2724
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2725
--
2726

    
2727
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2728
    LANGUAGE plpgsql STRICT
2729
    AS $_$
2730
DECLARE
2731
	view_qual_name text = util.qual_name(view_);
2732
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2733
BEGIN
2734
	EXECUTE $$
2735
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2736
  RETURNS integer AS
2737
$BODY1$
2738
SELECT $$||quote_ident(row_num_col)||$$
2739
FROM $$||view_qual_name||$$
2740
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2741
LIMIT 1
2742
$BODY1$
2743
  LANGUAGE sql STABLE
2744
  COST 100;
2745
$$;
2746
	
2747
	EXECUTE $$
2748
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2749
  RETURNS SETOF $$||view_||$$ AS
2750
$BODY1$
2751
SELECT * FROM $$||view_qual_name||$$
2752
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2753
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2754
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2755
ORDER BY $$||quote_ident(row_num_col)||$$
2756
$BODY1$
2757
  LANGUAGE sql STABLE
2758
  COST 100
2759
  ROWS 1000
2760
$$;
2761
	
2762
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2763
END;
2764
$_$;
2765

    
2766

    
2767
--
2768
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2769
--
2770

    
2771
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2772
    LANGUAGE plpgsql STRICT
2773
    AS $_$
2774
DECLARE
2775
	view_qual_name text = util.qual_name(view_);
2776
BEGIN
2777
	EXECUTE $$
2778
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2779
  RETURNS SETOF $$||view_||$$
2780
  SET enable_sort TO 'off'
2781
  AS
2782
$BODY1$
2783
SELECT * FROM $$||view_qual_name||$$($2, $3)
2784
$BODY1$
2785
  LANGUAGE sql STABLE
2786
  COST 100
2787
  ROWS 1000
2788
;
2789
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2790
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2791
If you want to run EXPLAIN and get expanded output, use the regular subset
2792
function instead. (When a config param is set on a function, EXPLAIN produces
2793
just a function scan.)
2794
';
2795
$$;
2796
END;
2797
$_$;
2798

    
2799

    
2800
--
2801
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2802
--
2803

    
2804
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2805
creates subset function which turns off enable_sort
2806
';
2807

    
2808

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

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

    
2821

    
2822
--
2823
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2824
--
2825

    
2826
CREATE FUNCTION name(table_ regclass) RETURNS text
2827
    LANGUAGE sql STABLE
2828
    AS $_$
2829
SELECT relname::text FROM pg_class WHERE oid = $1
2830
$_$;
2831

    
2832

    
2833
--
2834
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2835
--
2836

    
2837
CREATE FUNCTION name(type regtype) RETURNS text
2838
    LANGUAGE sql STABLE
2839
    AS $_$
2840
SELECT typname::text FROM pg_type WHERE oid = $1
2841
$_$;
2842

    
2843

    
2844
--
2845
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2846
--
2847

    
2848
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2849
    LANGUAGE sql IMMUTABLE
2850
    AS $_$
2851
SELECT octet_length($1) >= util.namedatalen() - $2
2852
$_$;
2853

    
2854

    
2855
--
2856
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2857
--
2858

    
2859
CREATE FUNCTION namedatalen() RETURNS integer
2860
    LANGUAGE sql IMMUTABLE
2861
    AS $$
2862
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2863
$$;
2864

    
2865

    
2866
--
2867
-- Name: new_world(); Type: FUNCTION; Schema: util; Owner: -
2868
--
2869

    
2870
CREATE FUNCTION new_world() RETURNS postgis.geography
2871
    LANGUAGE sql IMMUTABLE
2872
    SET search_path TO util
2873
    AS $$
2874
SELECT util.bounding_box(-56 ~ 83, 172 ~ -34)
2875
$$;
2876

    
2877

    
2878
--
2879
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2880
--
2881

    
2882
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2883
    LANGUAGE sql IMMUTABLE
2884
    AS $_$
2885
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2886
$_$;
2887

    
2888

    
2889
--
2890
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2891
--
2892

    
2893
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2894
    LANGUAGE sql IMMUTABLE
2895
    AS $_$
2896
SELECT $1 IS NOT NULL
2897
$_$;
2898

    
2899

    
2900
--
2901
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2902
--
2903

    
2904
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2905
    LANGUAGE sql IMMUTABLE
2906
    AS $_$
2907
SELECT util.hstore($1, NULL) || '*=>*'
2908
$_$;
2909

    
2910

    
2911
--
2912
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2913
--
2914

    
2915
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2916
for use with _map()
2917
';
2918

    
2919

    
2920
--
2921
-- Name: numrange(range); Type: FUNCTION; Schema: util; Owner: -
2922
--
2923

    
2924
CREATE FUNCTION numrange(value range) RETURNS numrange
2925
    LANGUAGE sql IMMUTABLE
2926
    AS $_$
2927
SELECT numrange($1.lower, $1.upper, $1.bounds)
2928
$_$;
2929

    
2930

    
2931
--
2932
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2933
--
2934

    
2935
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2936
    LANGUAGE sql IMMUTABLE
2937
    AS $_$
2938
SELECT $2 + COALESCE($1, 0)
2939
$_$;
2940

    
2941

    
2942
--
2943
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2944
--
2945

    
2946
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2947
    LANGUAGE sql STABLE
2948
    AS $_$
2949
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2950
$_$;
2951

    
2952

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

    
2957
CREATE FUNCTION pg_get_viewdef(view_ regclass) RETURNS text
2958
    LANGUAGE sql STABLE
2959
    AS $_$
2960
SELECT util.view_def_to_orig(pg_catalog.pg_get_viewdef($1))
2961
$_$;
2962

    
2963

    
2964
--
2965
-- Name: point(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
2966
--
2967

    
2968
CREATE FUNCTION point(latitude_deg double precision, longitude_deg double precision) RETURNS postgis.geography
2969
    LANGUAGE sql IMMUTABLE
2970
    AS $_$
2971
SELECT postgis.st_setsrid(postgis.st_point(/*x_lon=*/$2, /*y_lat=*/$1),
2972
/*WGS84*/4326)::postgis.geography
2973
$_$;
2974

    
2975

    
2976
--
2977
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2978
--
2979

    
2980
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2981
    LANGUAGE sql
2982
    AS $_$
2983
SELECT util.eval($$INSERT INTO $$||$1||$$
2984
$$||util.ltrim_nl($2));
2985
-- make sure the created table has the correct estimated row count
2986
SELECT util.analyze_($1);
2987
$_$;
2988

    
2989

    
2990
--
2991
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2992
--
2993

    
2994
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2995
    LANGUAGE sql IMMUTABLE
2996
    AS $_$
2997
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2998
$_$;
2999

    
3000

    
3001
--
3002
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3003
--
3004

    
3005
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
3006
    LANGUAGE sql
3007
    AS $_$
3008
SELECT util.set_comment($1, concat($2, util.comment($1)))
3009
$_$;
3010

    
3011

    
3012
--
3013
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
3014
--
3015

    
3016
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
3017
comment: must start and end with a newline
3018
';
3019

    
3020

    
3021
--
3022
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
3023
--
3024

    
3025
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
3026
    LANGUAGE sql IMMUTABLE
3027
    AS $_$
3028
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
3029
$_$;
3030

    
3031

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

    
3036
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
3037
    LANGUAGE sql STABLE
3038
    SET search_path TO pg_temp
3039
    AS $_$
3040
SELECT $1::text
3041
$_$;
3042

    
3043

    
3044
--
3045
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
3046
--
3047

    
3048
CREATE FUNCTION qual_name(type regtype) RETURNS text
3049
    LANGUAGE sql STABLE
3050
    SET search_path TO pg_temp
3051
    AS $_$
3052
SELECT $1::text
3053
$_$;
3054

    
3055

    
3056
--
3057
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
3058
--
3059

    
3060
COMMENT ON FUNCTION qual_name(type regtype) IS '
3061
a type''s schema-qualified name
3062
';
3063

    
3064

    
3065
--
3066
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
3067
--
3068

    
3069
CREATE FUNCTION qual_name(type unknown) RETURNS text
3070
    LANGUAGE sql STABLE
3071
    AS $_$
3072
SELECT util.qual_name($1::text::regtype)
3073
$_$;
3074

    
3075

    
3076
--
3077
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
3078
--
3079

    
3080
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
3081
    LANGUAGE sql IMMUTABLE
3082
    AS $_$
3083
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
3084
$_$;
3085

    
3086

    
3087
--
3088
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3089
--
3090

    
3091
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
3092
    LANGUAGE sql IMMUTABLE
3093
    AS $_$
3094
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
3095
$_$;
3096

    
3097

    
3098
--
3099
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
3100
--
3101

    
3102
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
3103
    LANGUAGE sql IMMUTABLE
3104
    AS $_$
3105
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
3106
$_$;
3107

    
3108

    
3109
--
3110
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
3111
--
3112

    
3113
CREATE FUNCTION raise(type text, msg text) RETURNS void
3114
    LANGUAGE sql IMMUTABLE
3115
    AS $_X$
3116
SELECT util.eval($$
3117
CREATE OR REPLACE FUNCTION pg_temp.__raise()
3118
  RETURNS void AS
3119
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
3120
$__BODY1$
3121
BEGIN
3122
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
3123
END;
3124
$__BODY1$
3125
  LANGUAGE plpgsql IMMUTABLE
3126
  COST 100;
3127
$$, verbose_ := false);
3128

    
3129
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
3130
$_X$;
3131

    
3132

    
3133
--
3134
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
3135
--
3136

    
3137
COMMENT ON FUNCTION raise(type text, msg text) IS '
3138
type: a log level from
3139
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
3140
or a condition name from
3141
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
3142
';
3143

    
3144

    
3145
--
3146
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
3147
--
3148

    
3149
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3150
    LANGUAGE sql IMMUTABLE
3151
    AS $_$
3152
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3153
$_$;
3154

    
3155

    
3156
--
3157
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3158
--
3159

    
3160
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3161
    LANGUAGE plpgsql IMMUTABLE STRICT
3162
    AS $$
3163
BEGIN
3164
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3165
END;
3166
$$;
3167

    
3168

    
3169
--
3170
-- Name: range(numeric, numeric); Type: FUNCTION; Schema: util; Owner: -
3171
--
3172

    
3173
CREATE FUNCTION range(lower numeric, upper numeric) RETURNS range
3174
    LANGUAGE sql IMMUTABLE
3175
    AS $_$
3176
SELECT ($1, $2, '[]')::util.range
3177
$_$;
3178

    
3179

    
3180
--
3181
-- Name: recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3182
--
3183

    
3184
CREATE FUNCTION recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
3185
    LANGUAGE plpgsql
3186
    AS $_$
3187
DECLARE
3188
	PG_EXCEPTION_DETAIL text;
3189
	restore_views_info util.restore_views_info;
3190
BEGIN
3191
	restore_views_info = util.save_drop_views(users);
3192
	
3193
	-- trigger the dependent_objects_still_exist exception
3194
	PERFORM util.eval(COALESCE(util.mk_drop_from_create(cmd), '')||cmd);
3195
		-- *not* CASCADE; it must trigger an exception
3196
	
3197
	PERFORM util.restore_views(restore_views_info);
3198
EXCEPTION
3199
WHEN dependent_objects_still_exist THEN
3200
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
3201
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
3202
	users = array(SELECT * FROM util.regexp_matches_group(
3203
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$'));
3204
		-- will be in forward dependency order
3205
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
3206
	PERFORM util.debug_print_var('users', users);
3207
	IF util.is_empty(users) THEN RAISE; END IF;
3208
	PERFORM util.recreate(cmd, users);
3209
END;
3210
$_$;
3211

    
3212

    
3213
--
3214
-- Name: FUNCTION recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
3215
--
3216

    
3217
COMMENT ON FUNCTION recreate(cmd text, users text[]) IS '
3218
the appropriate drop statement will be added automatically.
3219

    
3220
usage:
3221
SELECT util.recreate($$
3222
CREATE VIEW schema.main_view AS _;
3223

    
3224
-- manually restore views that need to be updated for the changes
3225
CREATE VIEW schema.dependent_view AS _;
3226
$$);
3227

    
3228
idempotent
3229

    
3230
users: not necessary to provide this because it will be autopopulated
3231
';
3232

    
3233

    
3234
--
3235
-- Name: recreate_view(regclass, text, text); Type: FUNCTION; Schema: util; Owner: -
3236
--
3237

    
3238
CREATE FUNCTION recreate_view(view_ regclass, view_query text DEFAULT NULL::text, dependent_view_changes text DEFAULT ''::text) RETURNS void
3239
    LANGUAGE sql
3240
    AS $_$
3241
SELECT util.recreate($$
3242
CREATE VIEW $$||$1||$$ AS 
3243
$$||COALESCE($2, pg_get_viewdef($1))||$$;
3244
$$||util.mk_set_relation_metadata($1)||$$
3245

    
3246
-- manually restore views that need to be updated for the changes
3247
$$||$3||$$
3248
$$);
3249
$_$;
3250

    
3251

    
3252
--
3253
-- Name: FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text); Type: COMMENT; Schema: util; Owner: -
3254
--
3255

    
3256
COMMENT ON FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text) IS '
3257
usage:
3258
SELECT util.recreate_view(''schema.main_view'', $$
3259
SELECT __
3260
$$, $$
3261
CREATE VIEW schema.dependent_view AS 
3262
__;
3263
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3264
$$);
3265

    
3266
if view has already been modified:
3267
SELECT util.recreate_view(''schema.main_view'', dependent_view_changes := $$
3268
CREATE VIEW schema.dependent_view AS 
3269
__;
3270
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3271
$$);
3272

    
3273
idempotent
3274
';
3275

    
3276

    
3277
--
3278
-- Name: regexp_match(text, text); Type: FUNCTION; Schema: util; Owner: -
3279
--
3280

    
3281
CREATE FUNCTION regexp_match(str text, re text) RETURNS text[]
3282
    LANGUAGE sql IMMUTABLE
3283
    AS $_$
3284
SELECT match FROM regexp_matches($1, $2) match LIMIT 1/*only 1st match*/
3285
$_$;
3286

    
3287

    
3288
--
3289
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3290
--
3291

    
3292
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3293
    LANGUAGE sql IMMUTABLE
3294
    AS $_$
3295
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3296
$_$;
3297

    
3298

    
3299
--
3300
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3301
--
3302

    
3303
CREATE FUNCTION regexp_quote(str text) RETURNS text
3304
    LANGUAGE sql IMMUTABLE
3305
    AS $_$
3306
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3307
$_$;
3308

    
3309

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

    
3314
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3315
    LANGUAGE sql IMMUTABLE
3316
    AS $_$
3317
SELECT (CASE WHEN right($1, 1) = ')'
3318
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3319
$_$;
3320

    
3321

    
3322
--
3323
-- Name: relation_exists(text); Type: FUNCTION; Schema: util; Owner: -
3324
--
3325

    
3326
CREATE FUNCTION relation_exists(relation text) RETURNS boolean
3327
    LANGUAGE sql STABLE
3328
    AS $_$
3329
SELECT $1 IS NOT NULL AND util.is_castable($1, NULL::regclass)
3330
$_$;
3331

    
3332

    
3333
--
3334
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3335
--
3336

    
3337
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3338
    LANGUAGE sql STABLE
3339
    AS $_$
3340
SELECT util.relation_type(util.relation_type_char($1))
3341
$_$;
3342

    
3343

    
3344
--
3345
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3346
--
3347

    
3348
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3349
    LANGUAGE sql IMMUTABLE
3350
    AS $_$
3351
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3352
$_$;
3353

    
3354

    
3355
--
3356
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3357
--
3358

    
3359
CREATE FUNCTION relation_type(type regtype) RETURNS text
3360
    LANGUAGE sql IMMUTABLE
3361
    AS $$
3362
SELECT 'TYPE'::text
3363
$$;
3364

    
3365

    
3366
--
3367
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
3368
--
3369

    
3370
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3371
    LANGUAGE sql STABLE
3372
    AS $_$
3373
SELECT relkind FROM pg_class WHERE oid = $1
3374
$_$;
3375

    
3376

    
3377
--
3378
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
3379
--
3380

    
3381
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3382
    LANGUAGE sql
3383
    AS $_$
3384
/* can't have in_table/out_table inherit from *each other*, because inheritance
3385
also causes the rows of the parent table to be included in the child table.
3386
instead, they need to inherit from a common, empty table. */
3387
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3388
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3389
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3390
SELECT util.inherit($2, $4);
3391
SELECT util.inherit($3, $4);
3392

    
3393
SELECT util.rematerialize_query($1, $$
3394
SELECT * FROM util.diff(
3395
  $$||util.quote_typed($2)||$$
3396
, $$||util.quote_typed($3)||$$
3397
, NULL::$$||$4||$$)
3398
$$);
3399

    
3400
/* the table unfortunately cannot be *materialized* in human-readable form,
3401
because this would create column name collisions between the two sides */
3402
SELECT util.prepend_comment($1, '
3403
to view this table in human-readable form (with each side''s tuple column
3404
expanded to its component fields):
3405
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3406

    
3407
to display NULL values that are extra or missing:
3408
SELECT * FROM '||$1||';
3409
');
3410
$_$;
3411

    
3412

    
3413
--
3414
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3415
--
3416

    
3417
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3418
type_table (*required*): table to create as the shared base type
3419
';
3420

    
3421

    
3422
--
3423
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3424
--
3425

    
3426
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3427
    LANGUAGE sql
3428
    AS $_$
3429
SELECT util.drop_table($1);
3430
SELECT util.materialize_query($1, $2);
3431
$_$;
3432

    
3433

    
3434
--
3435
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3436
--
3437

    
3438
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3439
idempotent, but repeats action each time
3440
';
3441

    
3442

    
3443
--
3444
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3445
--
3446

    
3447
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3448
    LANGUAGE sql
3449
    AS $_$
3450
SELECT util.drop_table($1);
3451
SELECT util.materialize_view($1, $2);
3452
$_$;
3453

    
3454

    
3455
--
3456
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3457
--
3458

    
3459
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3460
idempotent, but repeats action each time
3461
';
3462

    
3463

    
3464
--
3465
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3466
--
3467

    
3468
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3469
    LANGUAGE sql
3470
    AS $_$
3471
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3472
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3473
FROM util.col_names($1::text::regtype) f (name);
3474
SELECT NULL::void; -- don't fold away functions called in previous query
3475
$_$;
3476

    
3477

    
3478
--
3479
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3480
--
3481

    
3482
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3483
idempotent
3484
';
3485

    
3486

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

    
3491
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3492
    LANGUAGE sql
3493
    AS $_$
3494
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3495
included in the debug SQL */
3496
SELECT util.rename_relation(util.qual_name($1), $2)
3497
$_$;
3498

    
3499

    
3500
--
3501
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3502
--
3503

    
3504
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3505
    LANGUAGE sql
3506
    AS $_$
3507
/* 'ALTER TABLE can be used with views too'
3508
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3509
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3510
||quote_ident($2))
3511
$_$;
3512

    
3513

    
3514
--
3515
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3516
--
3517

    
3518
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3519
idempotent
3520
';
3521

    
3522

    
3523
--
3524
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3525
--
3526

    
3527
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3528
    LANGUAGE sql IMMUTABLE
3529
    AS $_$
3530
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3531
$_$;
3532

    
3533

    
3534
--
3535
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3536
--
3537

    
3538
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3539
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 
3540
';
3541

    
3542

    
3543
--
3544
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3545
--
3546

    
3547
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3548
    LANGUAGE sql
3549
    AS $_$
3550
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3551
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3552
SELECT util.set_col_names($1, $2);
3553
$_$;
3554

    
3555

    
3556
--
3557
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3558
--
3559

    
3560
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3561
idempotent.
3562
alters the names table, so it will need to be repopulated after running this function.
3563
';
3564

    
3565

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

    
3570
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3571
    LANGUAGE sql
3572
    AS $_$
3573
SELECT util.drop_table($1);
3574
SELECT util.mk_map_table($1);
3575
$_$;
3576

    
3577

    
3578
--
3579
-- Name: restore_views(restore_views_info); Type: FUNCTION; Schema: util; Owner: -
3580
--
3581

    
3582
CREATE FUNCTION restore_views(restore_views_info) RETURNS void
3583
    LANGUAGE sql
3584
    AS $_$
3585
SELECT util.debug_print_var('views', $1);
3586
SELECT util.create_if_not_exists((view_).def, (view_).path)
3587
	/* need to specify view name for manual existence check, in case view def
3588
	becomes invalid, which would produce nonstandard (uncatchable) exception */
3589
FROM unnest($1.views) view_; -- in forward dependency order
3590
	/* create_if_not_exists() rather than eval(), because cmd might manually
3591
	re-create a deleted dependent view, causing it to already exist */
3592
SELECT NULL::void; -- don't fold away functions called in previous query
3593
$_$;
3594

    
3595

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

    
3600
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3601
    LANGUAGE sql
3602
    AS $_$
3603
SELECT util.drop_column($1, $2, force := true)
3604
$_$;
3605

    
3606

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

    
3611
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3612
    LANGUAGE sql IMMUTABLE
3613
    AS $_$
3614
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3615
$_$;
3616

    
3617

    
3618
--
3619
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3620
--
3621

    
3622
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3623
    LANGUAGE sql IMMUTABLE
3624
    AS $_$
3625
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3626
ELSE util.mk_set_search_path(for_printing := true)||$$;
3627
$$ END)||$1
3628
$_$;
3629

    
3630

    
3631
--
3632
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3633
--
3634

    
3635
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3636
    LANGUAGE plpgsql STRICT
3637
    AS $$
3638
DECLARE
3639
	result text = NULL;
3640
BEGIN
3641
	BEGIN
3642
		result = util.show_create_view(view_, replace := false);
3643
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3644
			(eg. invalid_table_definition), instead of the standard
3645
			duplicate_table exception caught by util.create_if_not_exists() */
3646
		PERFORM util.drop_view(view_);
3647
	EXCEPTION
3648
		WHEN undefined_table THEN NULL;
3649
	END;
3650
	RETURN result;
3651
END;
3652
$$;
3653

    
3654

    
3655
--
3656
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3657
--
3658

    
3659
CREATE FUNCTION save_drop_views(views text[]) RETURNS restore_views_info
3660
    LANGUAGE sql
3661
    AS $_$
3662
SELECT ROW(/*return in forward dependency order*/util.array_reverse(array(
3663
SELECT (view_, util.save_drop_view(view_))::util.db_item
3664
FROM unnest(/*drop in reverse dependency order*/util.array_reverse($1)) view_
3665
)))::util.restore_views_info
3666
$_$;
3667

    
3668

    
3669
--
3670
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3671
--
3672

    
3673
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3674
    LANGUAGE sql STABLE
3675
    AS $_$
3676
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3677
$_$;
3678

    
3679

    
3680
--
3681
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3682
--
3683

    
3684
CREATE FUNCTION schema(table_ regclass) RETURNS text
3685
    LANGUAGE sql STABLE
3686
    AS $_$
3687
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3688
$_$;
3689

    
3690

    
3691
--
3692
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3693
--
3694

    
3695
CREATE FUNCTION schema(type regtype) RETURNS text
3696
    LANGUAGE sql STABLE
3697
    AS $_$
3698
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3699
$_$;
3700

    
3701

    
3702
--
3703
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3704
--
3705

    
3706
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3707
    LANGUAGE sql STABLE
3708
    AS $_$
3709
SELECT util.schema(pg_typeof($1))
3710
$_$;
3711

    
3712

    
3713
--
3714
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3715
--
3716

    
3717
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3718
    LANGUAGE sql STABLE
3719
    AS $_$
3720
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3721
$_$;
3722

    
3723

    
3724
--
3725
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3726
--
3727

    
3728
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3729
a schema bundle is a group of schemas with a common prefix
3730
';
3731

    
3732

    
3733
--
3734
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3735
--
3736

    
3737
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3738
    LANGUAGE sql
3739
    AS $_$
3740
SELECT util.schema_rename(old_schema,
3741
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3742
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3743
SELECT NULL::void; -- don't fold away functions called in previous query
3744
$_$;
3745

    
3746

    
3747
--
3748
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3749
--
3750

    
3751
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3752
    LANGUAGE plpgsql
3753
    AS $$
3754
BEGIN
3755
	-- don't schema_bundle_rm() the schema_bundle to keep!
3756
	IF replace = with_ THEN RETURN; END IF;
3757
	
3758
	PERFORM util.schema_bundle_rm(replace);
3759
	PERFORM util.schema_bundle_rename(with_, replace);
3760
END;
3761
$$;
3762

    
3763

    
3764
--
3765
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3766
--
3767

    
3768
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3769
    LANGUAGE sql
3770
    AS $_$
3771
SELECT util.schema_rm(schema)
3772
FROM util.schema_bundle_get_schemas($1) f (schema);
3773
SELECT NULL::void; -- don't fold away functions called in previous query
3774
$_$;
3775

    
3776

    
3777
--
3778
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3779
--
3780

    
3781
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3782
    LANGUAGE sql STABLE
3783
    AS $_$
3784
SELECT quote_ident(util.schema($1))
3785
$_$;
3786

    
3787

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

    
3792
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3793
    LANGUAGE sql IMMUTABLE
3794
    AS $_$
3795
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3796
$_$;
3797

    
3798

    
3799
--
3800
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3801
--
3802

    
3803
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3804
    LANGUAGE sql STABLE
3805
    AS $_$
3806
SELECT oid FROM pg_namespace WHERE nspname = $1
3807
$_$;
3808

    
3809

    
3810
--
3811
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3812
--
3813

    
3814
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3815
    LANGUAGE sql IMMUTABLE
3816
    AS $_$
3817
SELECT util.schema_regexp(schema_anchor := $1)
3818
$_$;
3819

    
3820

    
3821
--
3822
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3823
--
3824

    
3825
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3826
    LANGUAGE sql IMMUTABLE
3827
    AS $_$
3828
SELECT util.str_equality_regexp(util.schema($1))
3829
$_$;
3830

    
3831

    
3832
--
3833
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3834
--
3835

    
3836
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3837
    LANGUAGE sql
3838
    AS $_$
3839
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3840
$_$;
3841

    
3842

    
3843
--
3844
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3845
--
3846

    
3847
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3848
    LANGUAGE plpgsql
3849
    AS $$
3850
BEGIN
3851
	-- don't schema_rm() the schema to keep!
3852
	IF replace = with_ THEN RETURN; END IF;
3853
	
3854
	PERFORM util.schema_rm(replace);
3855
	PERFORM util.schema_rename(with_, replace);
3856
END;
3857
$$;
3858

    
3859

    
3860
--
3861
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3862
--
3863

    
3864
CREATE FUNCTION schema_rm(schema text) RETURNS void
3865
    LANGUAGE sql
3866
    AS $_$
3867
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3868
$_$;
3869

    
3870

    
3871
--
3872
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3873
--
3874

    
3875
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3876
    LANGUAGE sql
3877
    AS $_$
3878
SELECT util.eval(
3879
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3880
$_$;
3881

    
3882

    
3883
--
3884
-- Name: seq__create(text, integer); Type: FUNCTION; Schema: util; Owner: -
3885
--
3886

    
3887
CREATE FUNCTION seq__create(seq text, start integer DEFAULT 0) RETURNS void
3888
    LANGUAGE sql
3889
    AS $_$
3890
SELECT util.create_if_not_exists($$CREATE SEQUENCE $$||$1||$$ MINVALUE $$||$2,
3891
$1)
3892
$_$;
3893

    
3894

    
3895
--
3896
-- Name: FUNCTION seq__create(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
3897
--
3898

    
3899
COMMENT ON FUNCTION seq__create(seq text, start integer) IS '
3900
idempotent
3901
';
3902

    
3903

    
3904
--
3905
-- Name: seq__reset(text, integer); Type: FUNCTION; Schema: util; Owner: -
3906
--
3907

    
3908
CREATE FUNCTION seq__reset(seq text, start integer DEFAULT 0) RETURNS void
3909
    LANGUAGE sql
3910
    AS $_$
3911
SELECT util.seq__create($1, $2);
3912
SELECT util.eval($$ALTER SEQUENCE $$||$1||$$ RESTART$$);
3913
$_$;
3914

    
3915

    
3916
--
3917
-- Name: FUNCTION seq__reset(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
3918
--
3919

    
3920
COMMENT ON FUNCTION seq__reset(seq text, start integer) IS '
3921
creates sequence if doesn''t exist
3922

    
3923
idempotent
3924

    
3925
start: *note*: only used if sequence doesn''t exist
3926
';
3927

    
3928

    
3929
--
3930
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3931
--
3932

    
3933
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3934
    LANGUAGE plpgsql STRICT
3935
    AS $_$
3936
DECLARE
3937
    old text[] = ARRAY(SELECT util.col_names(table_));
3938
    new text[] = ARRAY(SELECT util.map_values(names));
3939
BEGIN
3940
    old = old[1:array_length(new, 1)]; -- truncate to same length
3941
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3942
||$$ TO $$||quote_ident(value))
3943
    FROM each(hstore(old, new))
3944
    WHERE value != key -- not same name
3945
    ;
3946
END;
3947
$_$;
3948

    
3949

    
3950
--
3951
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3952
--
3953

    
3954
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3955
idempotent
3956
';
3957

    
3958

    
3959
--
3960
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3961
--
3962

    
3963
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3964
    LANGUAGE plpgsql STRICT
3965
    AS $_$
3966
DECLARE
3967
	row_ util.map;
3968
BEGIN
3969
	-- rename any metadata cols rather than re-adding them with new names
3970
	BEGIN
3971
		PERFORM util.set_col_names(table_, names);
3972
	EXCEPTION
3973
		WHEN array_subscript_error THEN -- selective suppress
3974
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3975
				-- metadata cols not yet added
3976
			ELSE RAISE;
3977
			END IF;
3978
	END;
3979
	
3980
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3981
	LOOP
3982
		PERFORM util.mk_const_col((table_, row_."to"),
3983
			substring(row_."from" from 2));
3984
	END LOOP;
3985
	
3986
	PERFORM util.set_col_names(table_, names);
3987
END;
3988
$_$;
3989

    
3990

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

    
3995
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3996
idempotent.
3997
the metadata mappings must be *last* in the names table.
3998
';
3999

    
4000

    
4001
--
4002
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
4003
--
4004

    
4005
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
4006
    LANGUAGE sql
4007
    AS $_$
4008
SELECT util.eval(COALESCE(
4009
$$ALTER TABLE $$||$1||$$
4010
$$||(
4011
	SELECT
4012
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
4013
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
4014
, $$)
4015
	FROM
4016
	(
4017
		SELECT
4018
		  quote_ident(col_name) AS col_name_sql
4019
		, util.col_type(($1, col_name)) AS curr_type
4020
		, type AS target_type
4021
		FROM unnest($2)
4022
	) s
4023
	WHERE curr_type != target_type
4024
), ''))
4025
$_$;
4026

    
4027

    
4028
--
4029
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
4030
--
4031

    
4032
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
4033
idempotent
4034
';
4035

    
4036

    
4037
--
4038
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4039
--
4040

    
4041
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
4042
    LANGUAGE sql
4043
    AS $_$
4044
SELECT util.eval(util.mk_set_comment($1, $2))
4045
$_$;
4046

    
4047

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

    
4052
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
4053
    LANGUAGE sql
4054
    AS $_$
4055
SELECT util.eval(util.mk_set_search_path($1, $2))
4056
$_$;
4057

    
4058

    
4059
--
4060
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4061
--
4062

    
4063
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
4064
    LANGUAGE sql STABLE
4065
    AS $_$
4066
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
4067
||$1||$$ AS
4068
$$||pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
4069
$$||util.mk_set_relation_metadata($1)
4070
$_$;
4071

    
4072

    
4073
--
4074
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
4075
--
4076

    
4077
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
4078
    LANGUAGE sql STABLE
4079
    AS $_$
4080
SELECT string_agg(cmd, '')
4081
FROM
4082
(
4083
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
4084
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
4085
$$ ELSE '' END) AS cmd
4086
	FROM util.grants_users() f (user_)
4087
) s
4088
$_$;
4089

    
4090

    
4091
--
4092
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
4093
--
4094

    
4095
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
4096
    LANGUAGE sql STABLE
4097
    AS $_$
4098
SELECT oid FROM pg_class
4099
WHERE relkind = ANY($3) AND relname ~ $1
4100
AND util.schema_matches(util.schema(relnamespace), $2)
4101
ORDER BY relname
4102
$_$;
4103

    
4104

    
4105
--
4106
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
4107
--
4108

    
4109
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
4110
    LANGUAGE sql STABLE
4111
    AS $_$
4112
SELECT util.mk_set_comment($1, util.comment($1))
4113
$_$;
4114

    
4115

    
4116
--
4117
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4118
--
4119

    
4120
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
4121
    LANGUAGE sql STABLE
4122
    AS $_$
4123
SELECT oid
4124
FROM pg_type
4125
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
4126
ORDER BY typname
4127
$_$;
4128

    
4129

    
4130
--
4131
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4132
--
4133

    
4134
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
4135
    LANGUAGE sql STABLE
4136
    AS $_$
4137
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
4138
$_$;
4139

    
4140

    
4141
--
4142
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
4143
--
4144

    
4145
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
4146
    LANGUAGE sql IMMUTABLE
4147
    AS $_$
4148
SELECT '^'||util.regexp_quote($1)||'$'
4149
$_$;
4150

    
4151

    
4152
--
4153
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
4154
--
4155

    
4156
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
4157
    LANGUAGE plpgsql STABLE STRICT
4158
    AS $_$
4159
DECLARE
4160
    hstore hstore;
4161
BEGIN
4162
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
4163
        table_||$$))$$ INTO STRICT hstore;
4164
    RETURN hstore;
4165
END;
4166
$_$;
4167

    
4168

    
4169
--
4170
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4171
--
4172

    
4173
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
4174
    LANGUAGE sql STABLE
4175
    AS $_$
4176
SELECT COUNT(*) > 0 FROM pg_constraint
4177
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
4178
$_$;
4179

    
4180

    
4181
--
4182
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4183
--
4184

    
4185
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
4186
gets whether a status flag is set by the presence of a table constraint
4187
';
4188

    
4189

    
4190
--
4191
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4192
--
4193

    
4194
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
4195
    LANGUAGE sql
4196
    AS $_$
4197
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
4198
||quote_ident($2)||$$ CHECK (true)$$)
4199
$_$;
4200

    
4201

    
4202
--
4203
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4204
--
4205

    
4206
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
4207
stores a status flag by the presence of a table constraint.
4208
idempotent.
4209
';
4210

    
4211

    
4212
--
4213
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
4214
--
4215

    
4216
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
4217
    LANGUAGE sql STABLE
4218
    AS $_$
4219
SELECT util.table_flag__get($1, 'nulls_mapped')
4220
$_$;
4221

    
4222

    
4223
--
4224
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4225
--
4226

    
4227
COMMENT ON FUNCTION table_nulls_mapped__get(table_ regclass) IS '
4228
gets whether a table''s NULL-equivalent strings have been replaced with NULL
4229
';
4230

    
4231

    
4232
--
4233
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
4234
--
4235

    
4236
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
4237
    LANGUAGE sql
4238
    AS $_$
4239
SELECT util.table_flag__set($1, 'nulls_mapped')
4240
$_$;
4241

    
4242

    
4243
--
4244
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4245
--
4246

    
4247
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
4248
sets that a table''s NULL-equivalent strings have been replaced with NULL.
4249
idempotent.
4250
';
4251

    
4252

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

    
4257
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
4258
    LANGUAGE sql
4259
    AS $_$
4260
-- save data before truncating main table
4261
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
4262

    
4263
-- repopulate main table w/ copies column
4264
SELECT util.truncate($1);
4265
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
4266
SELECT util.populate_table($1, $$
4267
SELECT (table_).*, copies
4268
FROM (
4269
	SELECT table_, COUNT(*) AS copies
4270
	FROM pg_temp.__copy table_
4271
	GROUP BY table_
4272
) s
4273
$$);
4274

    
4275
-- delete temp table so it doesn't stay around until end of connection
4276
SELECT util.drop_table('pg_temp.__copy');
4277
$_$;
4278

    
4279

    
4280
--
4281
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
4282
--
4283

    
4284
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
4285
    LANGUAGE plpgsql STRICT
4286
    AS $_$
4287
DECLARE
4288
    row record;
4289
BEGIN
4290
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
4291
    LOOP
4292
        IF row.global_name != row.name THEN
4293
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
4294
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
4295
        END IF;
4296
    END LOOP;
4297
END;
4298
$_$;
4299

    
4300

    
4301
--
4302
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4303
--
4304

    
4305
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
4306
idempotent
4307
';
4308

    
4309

    
4310
--
4311
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4312
--
4313

    
4314
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
4315
    LANGUAGE sql
4316
    AS $_$
4317
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
4318
SELECT NULL::void; -- don't fold away functions called in previous query
4319
$_$;
4320

    
4321

    
4322
--
4323
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
4324
--
4325

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

    
4329
by default, cascadingly drops dependent columns so that they don''t prevent
4330
trim() from succeeding. note that this requires the dependent columns to then be
4331
manually re-created.
4332

    
4333
idempotent
4334
';
4335

    
4336

    
4337
--
4338
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4339
--
4340

    
4341
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4342
    LANGUAGE plpgsql STRICT
4343
    AS $_$
4344
BEGIN
4345
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4346
END;
4347
$_$;
4348

    
4349

    
4350
--
4351
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4352
--
4353

    
4354
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4355
idempotent
4356
';
4357

    
4358

    
4359
--
4360
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4361
--
4362

    
4363
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4364
    LANGUAGE sql IMMUTABLE
4365
    AS $_$
4366
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4367
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4368
$_$;
4369

    
4370

    
4371
--
4372
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4373
--
4374

    
4375
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4376
    LANGUAGE plpgsql IMMUTABLE
4377
    AS $$
4378
BEGIN
4379
	/* need explicit cast because some types not implicitly-castable, and also
4380
	to make the cast happen inside the try block. (*implicit* casts to the
4381
	return type happen at the end of the function, outside any block.) */
4382
	RETURN util.cast(value, ret_type_null);
4383
EXCEPTION
4384
WHEN   data_exception
4385
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
4386
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
4387
	THEN
4388
	PERFORM util.raise('WARNING', SQLERRM);
4389
	RETURN NULL;
4390
END;
4391
$$;
4392

    
4393

    
4394
--
4395
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4396
--
4397

    
4398
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4399
ret_type_null: NULL::ret_type
4400
';
4401

    
4402

    
4403
--
4404
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4405
--
4406

    
4407
CREATE FUNCTION try_create(sql text) RETURNS void
4408
    LANGUAGE plpgsql STRICT
4409
    AS $$
4410
BEGIN
4411
	PERFORM util.eval(sql);
4412
EXCEPTION
4413
WHEN   not_null_violation
4414
		/* trying to add NOT NULL column to parent table, which cascades to
4415
		child table whose values for the new column will be NULL */
4416
	OR wrong_object_type -- trying to alter a view's columns
4417
	OR undefined_column
4418
	OR duplicate_column
4419
THEN NULL;
4420
WHEN datatype_mismatch THEN
4421
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4422
	ELSE RAISE; -- rethrow
4423
	END IF;
4424
END;
4425
$$;
4426

    
4427

    
4428
--
4429
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4430
--
4431

    
4432
COMMENT ON FUNCTION try_create(sql text) IS '
4433
idempotent
4434
';
4435

    
4436

    
4437
--
4438
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4439
--
4440

    
4441
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4442
    LANGUAGE sql
4443
    AS $_$
4444
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4445
$_$;
4446

    
4447

    
4448
--
4449
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4450
--
4451

    
4452
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4453
idempotent
4454
';
4455

    
4456

    
4457
--
4458
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4459
--
4460

    
4461
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4462
    LANGUAGE sql IMMUTABLE
4463
    AS $_$
4464
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4465
$_$;
4466

    
4467

    
4468
--
4469
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4470
--
4471

    
4472
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4473
a type''s NOT NULL qualifier
4474
';
4475

    
4476

    
4477
--
4478
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4479
--
4480

    
4481
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4482
    LANGUAGE sql STABLE
4483
    AS $_$
4484
SELECT (attname::text, atttypid)::util.col_cast
4485
FROM pg_attribute
4486
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4487
ORDER BY attnum
4488
$_$;
4489

    
4490

    
4491
--
4492
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4493
--
4494

    
4495
CREATE FUNCTION typeof(value anyelement) RETURNS text
4496
    LANGUAGE sql IMMUTABLE
4497
    AS $_$
4498
SELECT util.qual_name(pg_typeof($1))
4499
$_$;
4500

    
4501

    
4502
--
4503
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4504
--
4505

    
4506
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4507
    LANGUAGE plpgsql STABLE
4508
    AS $_$
4509
DECLARE
4510
    type regtype;
4511
BEGIN
4512
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4513
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4514
    RETURN type;
4515
END;
4516
$_$;
4517

    
4518

    
4519
--
4520
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4521
--
4522

    
4523
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4524
    LANGUAGE sql
4525
    AS $_$
4526
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4527
$_$;
4528

    
4529

    
4530
--
4531
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4532
--
4533

    
4534
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4535
auto-appends util to the search_path to enable use of util operators
4536
';
4537

    
4538

    
4539
--
4540
-- Name: view_def_to_orig(text); Type: FUNCTION; Schema: util; Owner: -
4541
--
4542

    
4543
CREATE FUNCTION view_def_to_orig(view_def text) RETURNS text
4544
    LANGUAGE sql IMMUTABLE
4545
    AS $_$
4546
SELECT
4547
regexp_replace(
4548
regexp_replace(
4549
$1
4550
,
4551
/* unexpand expanded * expressions. any list of 6+ cols from the same table is
4552
treated as a * expression. */
4553
'((?:"[^"\s]+"|\w+)\.)(?:"[^"\s]+"|\w+)'||
4554
	/* 1st col, which lacks separator before.
4555
	*note*: can't prepend \y because it considers only \w chars, not " */
4556
'(,[[:blank:]]*
4557
[[:blank:]]*)\1(?:"[^"\s]+"|\w+)'|| -- 2nd col, which has separator before
4558
'(?:\2\1(?:"[^"\s]+"|\w+)){4,}', -- later cols, w/ same table name and separator
4559
'\1*'/*prefix w/ table*/,
4560
'g')
4561
,
4562
/* merge .* expressions resulting from a SELECT * of a join. any list of
4563
multiple .* expressions is treated as a SELECT * . */
4564
'(?:"[^"\s]+"|\w+)\.\*'||
4565
	/* 1st table, which lacks separator before.
4566
	*note*: can't prepend \y because it considers only \w chars, not " */
4567
'(,[[:blank:]]*
4568
[[:blank:]]*)(?:"[^"\s]+"|\w+)\.\*'|| -- 2nd table, which has separator before
4569
'(?:\1(?:"[^"\s]+"|\w+)\.\*)*', -- later tables, w/ same separator
4570
'*',
4571
'g')
4572
$_$;
4573

    
4574

    
4575
--
4576
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4577
--
4578

    
4579
CREATE AGGREGATE all_same(anyelement) (
4580
    SFUNC = all_same_transform,
4581
    STYPE = anyarray,
4582
    FINALFUNC = all_same_final
4583
);
4584

    
4585

    
4586
--
4587
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4588
--
4589

    
4590
COMMENT ON AGGREGATE all_same(anyelement) IS '
4591
includes NULLs in comparison
4592
';
4593

    
4594

    
4595
--
4596
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4597
--
4598

    
4599
CREATE AGGREGATE join_strs(text, text) (
4600
    SFUNC = join_strs_transform,
4601
    STYPE = text
4602
);
4603

    
4604

    
4605
--
4606
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4607
--
4608

    
4609
CREATE OPERATOR %== (
4610
    PROCEDURE = keys_eq,
4611
    LEFTARG = anyelement,
4612
    RIGHTARG = anyelement
4613
);
4614

    
4615

    
4616
--
4617
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4618
--
4619

    
4620
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4621
returns whether the map-keys of the compared values are the same
4622
(mnemonic: % is the Perl symbol for a hash map)
4623

    
4624
should be overridden for types that store both keys and values
4625

    
4626
used in a FULL JOIN to select which columns to join on
4627
';
4628

    
4629

    
4630
--
4631
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4632
--
4633

    
4634
CREATE OPERATOR -> (
4635
    PROCEDURE = map_get,
4636
    LEFTARG = regclass,
4637
    RIGHTARG = text
4638
);
4639

    
4640

    
4641
--
4642
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4643
--
4644

    
4645
CREATE OPERATOR => (
4646
    PROCEDURE = hstore,
4647
    LEFTARG = text[],
4648
    RIGHTARG = text
4649
);
4650

    
4651

    
4652
--
4653
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4654
--
4655

    
4656
COMMENT ON OPERATOR => (text[], text) IS '
4657
usage: array[''key1'', ...]::text[] => ''value''
4658
';
4659

    
4660

    
4661
--
4662
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4663
--
4664

    
4665
CREATE OPERATOR ?*>= (
4666
    PROCEDURE = is_populated_more_often_than,
4667
    LEFTARG = anyelement,
4668
    RIGHTARG = anyelement
4669
);
4670

    
4671

    
4672
--
4673
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4674
--
4675

    
4676
CREATE OPERATOR ?>= (
4677
    PROCEDURE = is_more_complete_than,
4678
    LEFTARG = anyelement,
4679
    RIGHTARG = anyelement
4680
);
4681

    
4682

    
4683
--
4684
-- Name: @; Type: OPERATOR; Schema: util; Owner: -
4685
--
4686

    
4687
CREATE OPERATOR @ (
4688
    PROCEDURE = postgis.st_coveredby,
4689
    LEFTARG = postgis.geography,
4690
    RIGHTARG = postgis.geography
4691
);
4692

    
4693

    
4694
--
4695
-- Name: OPERATOR @ (postgis.geography, postgis.geography); Type: COMMENT; Schema: util; Owner: -
4696
--
4697

    
4698
COMMENT ON OPERATOR @ (postgis.geography, postgis.geography) IS '
4699
can''t use && because it only compares 2D bounding boxes (which are geometry
4700
objects that do not support geocoordinate wraparound)
4701
';
4702

    
4703

    
4704
--
4705
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4706
--
4707

    
4708
CREATE OPERATOR ||% (
4709
    PROCEDURE = concat_esc,
4710
    LEFTARG = text,
4711
    RIGHTARG = text
4712
);
4713

    
4714

    
4715
--
4716
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4717
--
4718

    
4719
COMMENT ON OPERATOR ||% (text, text) IS '
4720
% indicates an identifier, as in Perl hashes and one of the x86 assembler syntaxes for registers
4721
';
4722

    
4723

    
4724
--
4725
-- Name: ~; Type: OPERATOR; Schema: util; Owner: -
4726
--
4727

    
4728
CREATE OPERATOR ~ (
4729
    PROCEDURE = range,
4730
    LEFTARG = numeric,
4731
    RIGHTARG = numeric
4732
);
4733

    
4734

    
4735
SET search_path = pg_catalog;
4736

    
4737
--
4738
-- Name: CAST (util.range AS numrange); Type: CAST; Schema: pg_catalog; Owner: -
4739
--
4740

    
4741
CREATE CAST (util.range AS numrange) WITH FUNCTION util.numrange(util.range) AS IMPLICIT;
4742

    
4743

    
4744
SET search_path = util, pg_catalog;
4745

    
4746
--
4747
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4748
--
4749

    
4750
CREATE TABLE map (
4751
    "from" text NOT NULL,
4752
    "to" text,
4753
    filter text,
4754
    notes text
4755
);
4756

    
4757

    
4758
--
4759
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4760
--
4761

    
4762

    
4763

    
4764
--
4765
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4766
--
4767

    
4768

    
4769

    
4770
--
4771
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4772
--
4773

    
4774
ALTER TABLE ONLY map
4775
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4776

    
4777

    
4778
--
4779
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4780
--
4781

    
4782
ALTER TABLE ONLY map
4783
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4784

    
4785

    
4786
--
4787
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4788
--
4789

    
4790
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4791

    
4792

    
4793
--
4794
-- PostgreSQL database dump complete
4795
--
4796

    
(21-21/31)