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 'IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.
24

    
25
NOTE: IMMUTABLE 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.';
26

    
27

    
28
SET search_path = util, pg_catalog;
29

    
30
--
31
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
32
--
33

    
34
CREATE TYPE col_cast AS (
35
	col_name text,
36
	type regtype
37
);
38

    
39

    
40
--
41
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
42
--
43

    
44
CREATE TYPE col_ref AS (
45
	table_ regclass,
46
	name text
47
);
48

    
49

    
50
--
51
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
52
--
53

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

    
61

    
62
--
63
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
64
--
65

    
66
CREATE TYPE datatype AS ENUM (
67
    'str',
68
    'float'
69
);
70

    
71

    
72
--
73
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
74
--
75

    
76
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
77
    LANGUAGE sql IMMUTABLE
78
    AS $_$
79
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
80
$_$;
81

    
82

    
83
--
84
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
85
--
86

    
87
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
88
    LANGUAGE sql IMMUTABLE
89
    AS $_$
90
SELECT bool_and(value)
91
FROM
92
(VALUES
93
      ($1)
94
    , ($2)
95
    , ($3)
96
    , ($4)
97
    , ($5)
98
)
99
AS v (value)
100
$_$;
101

    
102

    
103
--
104
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
105
--
106

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

    
109

    
110
--
111
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
112
--
113

    
114
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
115
    LANGUAGE sql IMMUTABLE
116
    AS $_$
117
SELECT avg(value)
118
FROM
119
(VALUES
120
      ($1)
121
    , ($2)
122
    , ($3)
123
    , ($4)
124
    , ($5)
125
)
126
AS v (value)
127
$_$;
128

    
129

    
130
--
131
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
132
--
133

    
134
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
135
    LANGUAGE sql IMMUTABLE STRICT
136
    AS $_$
137
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)
138
FROM 
139
(
140
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
141
    UNION ALL
142
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
143
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
144
)
145
matches (g)
146
$_$;
147

    
148

    
149
--
150
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
151
--
152

    
153
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
154
    LANGUAGE sql IMMUTABLE
155
    AS $_$
156
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
157
FROM
158
(VALUES
159
      ($1)
160
    , ($2/60)
161
    , ($3/60/60)
162
)
163
AS v (value)
164
$_$;
165

    
166

    
167
--
168
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
169
--
170

    
171
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
172
    LANGUAGE sql IMMUTABLE
173
    AS $_$
174
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
175
$_$;
176

    
177

    
178
--
179
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
180
--
181

    
182
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
183
    LANGUAGE sql IMMUTABLE
184
    AS $_$
185
SELECT $1 = $2
186
$_$;
187

    
188

    
189
--
190
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
191
--
192

    
193
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
194
    LANGUAGE sql IMMUTABLE
195
    AS $_$
196
-- Fix dates after threshold date
197
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
198
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
199
$_$;
200

    
201

    
202
--
203
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
204
--
205

    
206
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
207
    LANGUAGE sql IMMUTABLE
208
    AS $_$
209
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
210
$_$;
211

    
212

    
213
--
214
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
215
--
216

    
217
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
218
    LANGUAGE sql IMMUTABLE
219
    AS $_$
220
SELECT util._if($1 != '', $2, $3)
221
$_$;
222

    
223

    
224
--
225
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
226
--
227

    
228
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
229
    LANGUAGE sql IMMUTABLE
230
    AS $_$
231
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
232
$_$;
233

    
234

    
235
--
236
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
237
--
238

    
239
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
240
    LANGUAGE sql IMMUTABLE
241
    AS $_$
242
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
243
$_$;
244

    
245

    
246
--
247
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
248
--
249

    
250
CREATE FUNCTION _label(label text, value text) RETURNS text
251
    LANGUAGE sql IMMUTABLE
252
    AS $_$
253
SELECT coalesce($1 || ': ', '') || $2
254
$_$;
255

    
256

    
257
--
258
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
259
--
260

    
261
CREATE FUNCTION _lowercase(value text) RETURNS text
262
    LANGUAGE sql IMMUTABLE
263
    AS $_$
264
SELECT lower($1)
265
$_$;
266

    
267

    
268
--
269
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
270
--
271

    
272
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
273
    LANGUAGE plpgsql IMMUTABLE STRICT
274
    AS $$
275
DECLARE
276
    result value%TYPE := util._map(map, value::text)::unknown;
277
BEGIN
278
    RETURN result;
279
END;
280
$$;
281

    
282

    
283
--
284
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
285
--
286

    
287
CREATE FUNCTION _map(map hstore, value text) RETURNS text
288
    LANGUAGE plpgsql IMMUTABLE STRICT
289
    AS $$
290
DECLARE
291
    match text := map -> value;
292
BEGIN
293
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
294
        match := map -> '*'; -- use default entry
295
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
296
        END IF;
297
    END IF;
298
    
299
    -- Interpret result
300
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
301
    ELSIF match = '*' THEN RETURN value;
302
    ELSE RETURN match;
303
    END IF;
304
END;
305
$$;
306

    
307

    
308
--
309
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
310
--
311

    
312
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
313
    LANGUAGE sql IMMUTABLE
314
    AS $_$
315
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
316
$_$;
317

    
318

    
319
--
320
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
321
--
322

    
323
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
324
    LANGUAGE sql IMMUTABLE
325
    AS $_$
326
SELECT util.join_strs(value, '; ')
327
FROM
328
(
329
    SELECT *
330
    FROM
331
    (
332
        SELECT
333
        DISTINCT ON (value)
334
        *
335
        FROM
336
        (VALUES
337
              (1, $1)
338
            , (2, $2)
339
            , (3, $3)
340
            , (4, $4)
341
            , (5, $5)
342
            , (6, $6)
343
            , (7, $7)
344
            , (8, $8)
345
            , (9, $9)
346
            , (10, $10)
347
        )
348
        AS v (sort_order, value)
349
        WHERE value IS NOT NULL
350
    )
351
    AS v
352
    ORDER BY sort_order
353
)
354
AS v
355
$_$;
356

    
357

    
358
--
359
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
360
--
361

    
362
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
363
    LANGUAGE sql IMMUTABLE
364
    AS $_$
365
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
366
$_$;
367

    
368

    
369
--
370
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
371
--
372

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

    
407

    
408
--
409
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
410
--
411

    
412
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
413
    LANGUAGE sql IMMUTABLE
414
    AS $_$
415
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
416
$_$;
417

    
418

    
419
--
420
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
421
--
422

    
423
CREATE FUNCTION _not(value boolean) RETURNS boolean
424
    LANGUAGE sql IMMUTABLE
425
    AS $_$
426
SELECT NOT $1
427
$_$;
428

    
429

    
430
--
431
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
432
--
433

    
434
CREATE FUNCTION _now() RETURNS timestamp with time zone
435
    LANGUAGE sql STABLE
436
    AS $$
437
SELECT now()
438
$$;
439

    
440

    
441
--
442
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
443
--
444

    
445
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
446
    LANGUAGE sql IMMUTABLE
447
    AS $_$
448
SELECT util."_nullIf"($1, $2, $3::util.datatype)
449
$_$;
450

    
451

    
452
--
453
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
454
--
455

    
456
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
457
    LANGUAGE plpgsql IMMUTABLE
458
    AS $$
459
DECLARE
460
    type util.datatype NOT NULL := type; -- add NOT NULL
461
BEGIN
462
    IF type = 'str' THEN RETURN nullif(value::text, "null");
463
    -- Invalid value is ignored, but invalid null value generates error
464
    ELSIF type = 'float' THEN
465
        DECLARE
466
            -- Outside the try block so that invalid null value generates error
467
            "null" double precision := "null"::double precision;
468
        BEGIN
469
            RETURN nullif(value::double precision, "null");
470
        EXCEPTION
471
            WHEN data_exception THEN RETURN value; -- ignore invalid value
472
        END;
473
    END IF;
474
END;
475
$$;
476

    
477

    
478
--
479
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
480
--
481

    
482
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
483
    LANGUAGE sql IMMUTABLE
484
    AS $_$
485
SELECT bool_or(value)
486
FROM
487
(VALUES
488
      ($1)
489
    , ($2)
490
    , ($3)
491
    , ($4)
492
    , ($5)
493
)
494
AS v (value)
495
$_$;
496

    
497

    
498
--
499
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
500
--
501

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

    
504

    
505
--
506
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
507
--
508

    
509
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
510
    LANGUAGE sql IMMUTABLE
511
    AS $_$
512
SELECT $2 - $1
513
$_$;
514

    
515

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

    
520
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
521
    LANGUAGE sql IMMUTABLE
522
    AS $_$
523
SELECT regexp_split_to_table($1, $2)
524
$_$;
525

    
526

    
527
--
528
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
529
--
530

    
531
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
532
    LANGUAGE sql STABLE STRICT
533
    AS $_$
534
SELECT util.derived_cols($1, $2)
535
UNION
536
SELECT util.eval2set($$
537
SELECT col
538
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
539
JOIN $$||$2||$$ ON "to" = col
540
WHERE "from" LIKE ':%'
541
$$, NULL::text)
542
$_$;
543

    
544

    
545
--
546
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
547
--
548

    
549
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS 'gets table_''s added columns (all the columns not in the original data)';
550

    
551

    
552
--
553
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
554
--
555

    
556
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
557
    LANGUAGE sql IMMUTABLE
558
    AS $_$
559
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
560
$_$;
561

    
562

    
563
--
564
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
565
--
566

    
567
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
568
    LANGUAGE plpgsql IMMUTABLE
569
    AS $$
570
DECLARE
571
	value_cmp         state%TYPE = ARRAY[value];
572
	state             state%TYPE = COALESCE(state, value_cmp);
573
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
574
BEGIN
575
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
576
END;
577
$$;
578

    
579

    
580
--
581
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
582
--
583

    
584
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
585
    LANGUAGE sql IMMUTABLE
586
    AS $_$
587
SELECT pg_catalog.array_fill($1, ARRAY[$2])
588
$_$;
589

    
590

    
591
--
592
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
593
--
594

    
595
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
596
    LANGUAGE sql IMMUTABLE
597
    AS $_$
598
SELECT util.array_length($1, 1)
599
$_$;
600

    
601

    
602
--
603
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
604
--
605

    
606
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
607
    LANGUAGE sql IMMUTABLE
608
    AS $_$
609
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
610
$_$;
611

    
612

    
613
--
614
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
615
--
616

    
617
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS 'returns 0 instead of NULL for empty arrays';
618

    
619

    
620
--
621
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
622
--
623

    
624
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
625
    LANGUAGE sql STABLE STRICT
626
    AS $_$
627
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
628
$_$;
629

    
630

    
631
--
632
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
633
--
634

    
635
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
636
    LANGUAGE plpgsql STRICT
637
    AS $_$
638
BEGIN
639
    -- not yet clustered (ARRAY[] compares NULLs literally)
640
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
641
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
642
    END IF;
643
END;
644
$_$;
645

    
646

    
647
--
648
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
649
--
650

    
651
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
652

    
653

    
654
--
655
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
656
--
657

    
658
CREATE FUNCTION col__min(col col_ref) RETURNS integer
659
    LANGUAGE sql STABLE
660
    AS $_$
661
SELECT util.eval2val($$
662
SELECT $$||quote_ident($1.name)||$$
663
FROM $$||$1.table_||$$
664
ORDER BY $$||quote_ident($1.name)||$$ ASC
665
LIMIT 1
666
$$, NULL::integer)
667
$_$;
668

    
669

    
670
--
671
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
672
--
673

    
674
CREATE FUNCTION col_comment(col col_ref) RETURNS text
675
    LANGUAGE plpgsql STABLE STRICT
676
    AS $$
677
DECLARE
678
	comment text;
679
BEGIN
680
	SELECT description
681
	FROM pg_attribute
682
	LEFT JOIN pg_description ON objoid = attrelid
683
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
684
	WHERE attrelid = col.table_ AND attname = col.name
685
	INTO STRICT comment
686
	;
687
	RETURN comment;
688
EXCEPTION
689
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
690
END;
691
$$;
692

    
693

    
694
--
695
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
696
--
697

    
698
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
699
    LANGUAGE plpgsql STABLE STRICT
700
    AS $$
701
DECLARE
702
	default_sql text;
703
BEGIN
704
	SELECT adsrc
705
	FROM pg_attribute
706
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
707
	WHERE attrelid = col.table_ AND attname = col.name
708
	INTO STRICT default_sql
709
	;
710
	RETURN default_sql;
711
EXCEPTION
712
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
713
END;
714
$$;
715

    
716

    
717
--
718
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
719
--
720

    
721
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
722
    LANGUAGE sql STABLE
723
    AS $_$
724
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
725
$_$;
726

    
727

    
728
--
729
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
730
--
731

    
732
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
733

    
734

    
735
--
736
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
737
--
738

    
739
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
740
    LANGUAGE plpgsql STRICT
741
    AS $$
742
BEGIN
743
    PERFORM util.col_type(col);
744
    RETURN true;
745
EXCEPTION
746
    WHEN undefined_column THEN RETURN false;
747
END;
748
$$;
749

    
750

    
751
--
752
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
753
--
754

    
755
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
756
    LANGUAGE plpgsql STABLE STRICT
757
    AS $$
758
DECLARE
759
    prefix text := util.name(type)||'.';
760
BEGIN
761
    RETURN QUERY
762
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
763
        FROM util.col_names(type) f (name_);
764
END;
765
$$;
766

    
767

    
768
--
769
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
770
--
771

    
772
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
773
    LANGUAGE sql STABLE STRICT
774
    AS $_$
775
SELECT attname::text
776
FROM pg_attribute
777
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
778
ORDER BY attnum
779
$_$;
780

    
781

    
782
--
783
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
784
--
785

    
786
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
787
    LANGUAGE plpgsql STABLE STRICT
788
    AS $_$
789
BEGIN
790
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
791
END;
792
$_$;
793

    
794

    
795
--
796
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
797
--
798

    
799
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
800
    LANGUAGE plpgsql STABLE STRICT
801
    AS $$
802
DECLARE
803
    type regtype;
804
BEGIN
805
    SELECT atttypid FROM pg_attribute
806
    WHERE attrelid = col.table_ AND attname = col.name
807
    INTO STRICT type
808
    ;
809
    RETURN type;
810
EXCEPTION
811
    WHEN no_data_found THEN
812
        RAISE undefined_column USING MESSAGE =
813
            concat('undefined column: ', col.name);
814
END;
815
$$;
816

    
817

    
818
--
819
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
820
--
821

    
822
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
823
    LANGUAGE sql IMMUTABLE
824
    AS $_$
825
SELECT util.esc_name__append($2, $1)
826
$_$;
827

    
828

    
829
--
830
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
831
--
832

    
833
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
834
    LANGUAGE sql IMMUTABLE
835
    AS $_$
836
SELECT position($1 in $2) > 0 /*1-based offset*/
837
$_$;
838

    
839

    
840
--
841
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
842
--
843

    
844
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
845
    LANGUAGE plpgsql STRICT
846
    AS $$
847
BEGIN
848
    PERFORM util.eval(sql);
849
EXCEPTION
850
    WHEN duplicate_table  THEN NULL;
851
    WHEN duplicate_object THEN NULL; -- e.g. constraint
852
    WHEN duplicate_column THEN NULL;
853
    WHEN invalid_table_definition THEN
854
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
855
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
856
        END IF;
857
END;
858
$$;
859

    
860

    
861
--
862
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
863
--
864

    
865
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
866

    
867

    
868
--
869
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
870
--
871

    
872
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
873
    LANGUAGE sql STABLE STRICT
874
    AS $_$
875
SELECT util.eval2set($$
876
SELECT col
877
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
878
LEFT JOIN $$||$2||$$ ON "to" = col
879
WHERE "from" IS NULL
880
$$, NULL::text)
881
$_$;
882

    
883

    
884
--
885
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
886
--
887

    
888
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS 'gets table_''s derived columns (all the columns not in the names table)';
889

    
890

    
891
--
892
-- Name: diff_cols(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
893
--
894

    
895
CREATE FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
896
    LANGUAGE sql STABLE
897
    AS $_$
898
SELECT * FROM
899
util.eval2col_pair($$
900
SELECT * FROM
901
(
902
$$||$1||$$
903
) left_ (left_)
904
FULL JOIN
905
(
906
$$||$2||$$
907
) right_ (right_)
908
ON left_ = right_
909
WHERE left_ IS DISTINCT FROM right_
910
ORDER BY left_, right_
911
$$, $3)
912
$_$;
913

    
914

    
915
--
916
-- Name: FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
917
--
918

    
919
COMMENT ON FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS 'col_type_null (*required*): NULL::col_type
920
usage:
921
SELECT * FROM util.diff_cols($$VALUES (''1''), (''2''), (''4'')$$, $$VALUES (''1''), (''3''), (''4'')$$, NULL::text)
922

    
923
to run EXPLAIN on the FULL JOIN query:
924
# run this function
925
# look for a NOTICE containing the expanded query that it ran
926
# run EXPLAIN on this expanded query
927
';
928

    
929

    
930
--
931
-- Name: diff_views(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
932
--
933

    
934
CREATE FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
935
    LANGUAGE sql STABLE
936
    AS $_$
937
SELECT * FROM util.diff_cols($$SELECT * FROM $$||$1, $$SELECT * FROM $$||$1, $3)
938
$_$;
939

    
940

    
941
--
942
-- Name: FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
943
--
944

    
945
COMMENT ON FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS 'col_type_null (*required*): NULL::col_type
946
usage:
947
SELECT * FROM util.diff_views(''"left_view"'', ''"right_view"'', NULL::text)
948
';
949

    
950

    
951
--
952
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
953
--
954

    
955
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
956
    LANGUAGE sql STRICT
957
    AS $_$
958
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
959
$_$;
960

    
961

    
962
--
963
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
964
--
965

    
966
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
967

    
968

    
969
--
970
-- Name: drop_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
971
--
972

    
973
CREATE FUNCTION drop_column(col col_ref) RETURNS void
974
    LANGUAGE sql STRICT
975
    AS $_$
976
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
977
quote_ident($1.name))
978
$_$;
979

    
980

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

    
985
COMMENT ON FUNCTION drop_column(col col_ref) IS 'idempotent';
986

    
987

    
988
--
989
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
990
--
991

    
992
CREATE FUNCTION drop_table(table_ text) RETURNS void
993
    LANGUAGE sql STRICT
994
    AS $_$
995
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
996
$_$;
997

    
998

    
999
--
1000
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
1001
--
1002

    
1003
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
1004

    
1005

    
1006
--
1007
-- Name: drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1008
--
1009

    
1010
CREATE FUNCTION drop_view(view_ text) RETURNS void
1011
    LANGUAGE sql STRICT
1012
    AS $_$
1013
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1)
1014
$_$;
1015

    
1016

    
1017
--
1018
-- Name: FUNCTION drop_view(view_ text); Type: COMMENT; Schema: util; Owner: -
1019
--
1020

    
1021
COMMENT ON FUNCTION drop_view(view_ text) IS 'idempotent';
1022

    
1023

    
1024
--
1025
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1026
--
1027

    
1028
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1029
    LANGUAGE sql IMMUTABLE
1030
    AS $_$
1031
SELECT util.array_fill($1, 0)
1032
$_$;
1033

    
1034

    
1035
--
1036
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1037
--
1038

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

    
1041

    
1042
--
1043
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1044
--
1045

    
1046
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1047
    LANGUAGE sql IMMUTABLE
1048
    AS $_$
1049
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1050
$_$;
1051

    
1052

    
1053
--
1054
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1055
--
1056

    
1057
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1058
    LANGUAGE sql IMMUTABLE
1059
    AS $_$
1060
SELECT regexp_replace($2, '("?)$', $1||'\1')
1061
$_$;
1062

    
1063

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

    
1068
CREATE FUNCTION eval(sql text) RETURNS void
1069
    LANGUAGE plpgsql STRICT
1070
    AS $$
1071
BEGIN
1072
    RAISE NOTICE '%', sql;
1073
    EXECUTE sql;
1074
END;
1075
$$;
1076

    
1077

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

    
1082
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1083
    LANGUAGE plpgsql
1084
    AS $$
1085
BEGIN
1086
	RAISE NOTICE '%', sql;
1087
	RETURN QUERY EXECUTE sql;
1088
END;
1089
$$;
1090

    
1091

    
1092
--
1093
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1094
--
1095

    
1096
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS 'col_type_null (*required*): NULL::col_type';
1097

    
1098

    
1099
--
1100
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1101
--
1102

    
1103
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1104
    LANGUAGE plpgsql
1105
    AS $$
1106
BEGIN
1107
	RAISE NOTICE '%', sql;
1108
	RETURN QUERY EXECUTE sql;
1109
END;
1110
$$;
1111

    
1112

    
1113
--
1114
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1115
--
1116

    
1117
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
1118

    
1119

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

    
1124
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1125
    LANGUAGE plpgsql
1126
    AS $$
1127
DECLARE
1128
	ret_val ret_type_null%TYPE;
1129
BEGIN
1130
	RAISE NOTICE '%', sql;
1131
	EXECUTE sql INTO STRICT ret_val;
1132
	RETURN ret_val;
1133
END;
1134
$$;
1135

    
1136

    
1137
--
1138
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1139
--
1140

    
1141
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
1142

    
1143

    
1144
--
1145
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1146
--
1147

    
1148
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1149
    LANGUAGE sql
1150
    AS $_$
1151
SELECT util.eval2val($$SELECT $$||$1, $2)
1152
$_$;
1153

    
1154

    
1155
--
1156
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1157
--
1158

    
1159
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS 'ret_type_null: NULL::ret_type';
1160

    
1161

    
1162
--
1163
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1164
--
1165

    
1166
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1167
    LANGUAGE sql
1168
    AS $_$
1169
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1170
$_$;
1171

    
1172

    
1173
--
1174
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1175
--
1176

    
1177
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1178
ret_type_null: NULL::ret_type';
1179

    
1180

    
1181
--
1182
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1183
--
1184

    
1185
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1186
    LANGUAGE sql STABLE STRICT
1187
    AS $_$
1188
SELECT col_name
1189
FROM unnest($2) s (col_name)
1190
WHERE util.col_exists(($1, col_name))
1191
$_$;
1192

    
1193

    
1194
--
1195
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1196
--
1197

    
1198
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1199
    LANGUAGE sql
1200
    AS $_$
1201
SELECT util.eval2set($$EXPLAIN $$||$1)
1202
$_$;
1203

    
1204

    
1205
--
1206
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1207
--
1208

    
1209
CREATE FUNCTION explain2notice(sql text) RETURNS void
1210
    LANGUAGE plpgsql
1211
    AS $_$
1212
BEGIN
1213
	RAISE NOTICE '%', $$EXPLAIN:
1214
$$||util.explain2str(sql);
1215
END;
1216
$_$;
1217

    
1218

    
1219
--
1220
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1221
--
1222

    
1223
CREATE FUNCTION explain2str(sql text) RETURNS text
1224
    LANGUAGE sql
1225
    AS $_$
1226
SELECT util.join_strs(explain, $$
1227
$$) FROM util.explain($1)
1228
$_$;
1229

    
1230

    
1231
SET default_tablespace = '';
1232

    
1233
SET default_with_oids = false;
1234

    
1235
--
1236
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1237
--
1238

    
1239
CREATE TABLE explain (
1240
    line text NOT NULL
1241
);
1242

    
1243

    
1244
--
1245
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1246
--
1247

    
1248
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1249
    LANGUAGE sql
1250
    AS $_$
1251
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1252
$$||quote_nullable($1)||$$
1253
)$$)
1254
$_$;
1255

    
1256

    
1257
--
1258
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1259
--
1260

    
1261
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS 'usage:
1262
PERFORM util.explain2table($$
1263
query
1264
$$);';
1265

    
1266

    
1267
--
1268
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1269
--
1270

    
1271
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1272
    LANGUAGE sql IMMUTABLE
1273
    AS $_$
1274
-- STRICT handles NULLs, so that the array will always be a value
1275
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1276
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1277
) END
1278
$_$;
1279

    
1280

    
1281
--
1282
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1283
--
1284

    
1285
COMMENT ON FUNCTION fix_array("array" anyarray) IS 'ensures that an array will always have proper non-NULL dimensions';
1286

    
1287

    
1288
--
1289
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1290
--
1291

    
1292
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1293
    LANGUAGE plpgsql
1294
    AS $_$
1295
DECLARE
1296
	PG_EXCEPTION_DETAIL text;
1297
	recreate_users_cmd text = util.save_drop_views(users);
1298
BEGIN
1299
	PERFORM util.eval(cmd);
1300
	PERFORM util.eval(recreate_users_cmd);
1301
EXCEPTION
1302
WHEN dependent_objects_still_exist THEN
1303
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1304
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1305
	users = array(SELECT * FROM util.regexp_matches_group(
1306
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1307
	IF util.is_empty(users) THEN RAISE; END IF;
1308
	PERFORM util.force_recreate(cmd, users);
1309
END;
1310
$_$;
1311

    
1312

    
1313
--
1314
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1315
--
1316

    
1317
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS 'idempotent
1318

    
1319
users: not necessary to provide this because it will be autopopulated';
1320

    
1321

    
1322
--
1323
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1324
--
1325

    
1326
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1327
    LANGUAGE plpgsql STRICT
1328
    AS $_$
1329
DECLARE
1330
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1331
$$||query;
1332
BEGIN
1333
	EXECUTE mk_view;
1334
EXCEPTION
1335
WHEN invalid_table_definition THEN
1336
	IF SQLERRM = 'cannot drop columns from view'
1337
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1338
	THEN
1339
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1340
		EXECUTE mk_view;
1341
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1342
	END IF;
1343
END;
1344
$_$;
1345

    
1346

    
1347
--
1348
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1349
--
1350

    
1351
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1352

    
1353

    
1354
--
1355
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1356
--
1357

    
1358
CREATE FUNCTION grants_users() RETURNS SETOF text
1359
    LANGUAGE sql IMMUTABLE
1360
    AS $$
1361
VALUES ('bien_read'), ('public_')
1362
$$;
1363

    
1364

    
1365
--
1366
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1367
--
1368

    
1369
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1370
    LANGUAGE sql IMMUTABLE
1371
    AS $_$
1372
SELECT substring($2 for length($1)) = $1
1373
$_$;
1374

    
1375

    
1376
--
1377
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1378
--
1379

    
1380
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1381
    LANGUAGE sql IMMUTABLE
1382
    AS $_$
1383
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1384
$_$;
1385

    
1386

    
1387
--
1388
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1389
--
1390

    
1391
COMMENT ON FUNCTION hstore(keys text[], value text) IS 'avoids repeating the same value for each key';
1392

    
1393

    
1394
--
1395
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1396
--
1397

    
1398
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1399
    LANGUAGE sql IMMUTABLE
1400
    AS $_$
1401
SELECT COALESCE($1, $2)
1402
$_$;
1403

    
1404

    
1405
--
1406
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1407
--
1408

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

    
1411

    
1412
--
1413
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1414
--
1415

    
1416
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1417
    LANGUAGE sql STABLE STRICT
1418
    AS $_$
1419
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1420
$_$;
1421

    
1422

    
1423
--
1424
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1425
--
1426

    
1427
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1428
    LANGUAGE sql IMMUTABLE
1429
    AS $_$
1430
SELECT util.array_length($1) = 0
1431
$_$;
1432

    
1433

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

    
1438
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1439
    LANGUAGE sql IMMUTABLE
1440
    AS $_$
1441
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1442
$_$;
1443

    
1444

    
1445
--
1446
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1447
--
1448

    
1449
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1450
    LANGUAGE sql IMMUTABLE
1451
    AS $_$
1452
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1453
$_$;
1454

    
1455

    
1456
--
1457
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1458
--
1459

    
1460
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1461
    LANGUAGE sql IMMUTABLE STRICT
1462
    AS $_$
1463
SELECT $1 || $3 || $2
1464
$_$;
1465

    
1466

    
1467
--
1468
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1469
--
1470

    
1471
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1472
    LANGUAGE sql IMMUTABLE
1473
    AS $_$
1474
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1475
$_$;
1476

    
1477

    
1478
--
1479
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1480
--
1481

    
1482
CREATE FUNCTION map_filter_insert() RETURNS trigger
1483
    LANGUAGE plpgsql
1484
    AS $$
1485
BEGIN
1486
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1487
	RETURN new;
1488
END;
1489
$$;
1490

    
1491

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

    
1496
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1497
    LANGUAGE plpgsql STABLE STRICT
1498
    AS $_$
1499
DECLARE
1500
    value text;
1501
BEGIN
1502
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1503
        INTO value USING key;
1504
    RETURN value;
1505
END;
1506
$_$;
1507

    
1508

    
1509
--
1510
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1511
--
1512

    
1513
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1514
    LANGUAGE sql IMMUTABLE
1515
    AS $_$
1516
SELECT util._map(util.nulls_map($1), $2)
1517
$_$;
1518

    
1519

    
1520
--
1521
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1522
--
1523

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

    
1526
[1] inlining of function calls, which is different from constant folding
1527
[2] _map()''s profiling query
1528
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1529
and map_nulls()''s profiling query
1530
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1531
both take ~920 ms.
1532
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.';
1533

    
1534

    
1535
--
1536
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1537
--
1538

    
1539
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1540
    LANGUAGE plpgsql STABLE STRICT
1541
    AS $_$
1542
BEGIN
1543
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1544
END;
1545
$_$;
1546

    
1547

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

    
1552
CREATE FUNCTION materialize_query(view_ text, sql text) RETURNS void
1553
    LANGUAGE sql
1554
    AS $_$
1555
SELECT util.create_if_not_exists($$CREATE TABLE $$||quote_ident($1)||$$ AS
1556
$$||$2)
1557
$_$;
1558

    
1559

    
1560
--
1561
-- Name: FUNCTION materialize_query(view_ text, sql text); Type: COMMENT; Schema: util; Owner: -
1562
--
1563

    
1564
COMMENT ON FUNCTION materialize_query(view_ text, sql text) IS 'idempotent';
1565

    
1566

    
1567
--
1568
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
1569
--
1570

    
1571
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1572
    LANGUAGE sql STRICT
1573
    AS $_$
1574
SELECT util.create_if_not_exists($$
1575
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1576
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1577
||quote_literal($2)||$$;
1578
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1579
$$)
1580
$_$;
1581

    
1582

    
1583
--
1584
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1585
--
1586

    
1587
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1588

    
1589

    
1590
--
1591
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1592
--
1593

    
1594
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1595
    LANGUAGE plpgsql STRICT
1596
    AS $_$
1597
DECLARE
1598
    type regtype = util.typeof(expr, col.table_::text::regtype);
1599
    col_name_sql text = quote_ident(col.name);
1600
BEGIN
1601
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1602
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1603
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1604
$$||expr||$$;
1605
$$);
1606
END;
1607
$_$;
1608

    
1609

    
1610
--
1611
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1612
--
1613

    
1614
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS 'idempotent';
1615

    
1616

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

    
1621
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1622
    LANGUAGE sql STRICT
1623
    AS $_$
1624
SELECT util.create_if_not_exists($$
1625
CREATE TABLE $$||$1||$$
1626
(
1627
    LIKE util.map INCLUDING ALL
1628
);
1629

    
1630
CREATE TRIGGER map_filter_insert
1631
  BEFORE INSERT
1632
  ON $$||$1||$$
1633
  FOR EACH ROW
1634
  EXECUTE PROCEDURE util.map_filter_insert();
1635
$$)
1636
$_$;
1637

    
1638

    
1639
--
1640
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1641
--
1642

    
1643
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1644
    LANGUAGE sql STRICT
1645
    AS $_$
1646
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1647
$_$;
1648

    
1649

    
1650
--
1651
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1652
--
1653

    
1654
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1655

    
1656

    
1657
--
1658
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1659
--
1660

    
1661
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1662
    LANGUAGE plpgsql STRICT
1663
    AS $_$
1664
DECLARE
1665
	view_qual_name text = util.qual_name(view_);
1666
BEGIN
1667
	EXECUTE $$
1668
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1669
  RETURNS SETOF $$||view_||$$ AS
1670
$BODY1$
1671
SELECT * FROM $$||view_qual_name||$$
1672
ORDER BY sort_col
1673
LIMIT $1 OFFSET $2
1674
$BODY1$
1675
  LANGUAGE sql STABLE
1676
  COST 100
1677
  ROWS 1000
1678
$$;
1679
	
1680
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1681
END;
1682
$_$;
1683

    
1684

    
1685
--
1686
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1687
--
1688

    
1689
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1690
    LANGUAGE plpgsql STRICT
1691
    AS $_$
1692
DECLARE
1693
	view_qual_name text = util.qual_name(view_);
1694
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1695
BEGIN
1696
	EXECUTE $$
1697
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1698
  RETURNS integer AS
1699
$BODY1$
1700
SELECT $$||quote_ident(row_num_col)||$$
1701
FROM $$||view_qual_name||$$
1702
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1703
LIMIT 1
1704
$BODY1$
1705
  LANGUAGE sql STABLE
1706
  COST 100;
1707
$$;
1708
	
1709
	EXECUTE $$
1710
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1711
  RETURNS SETOF $$||view_||$$ AS
1712
$BODY1$
1713
SELECT * FROM $$||view_qual_name||$$
1714
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1715
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1716
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1717
ORDER BY $$||quote_ident(row_num_col)||$$
1718
$BODY1$
1719
  LANGUAGE sql STABLE
1720
  COST 100
1721
  ROWS 1000
1722
$$;
1723
	
1724
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1725
END;
1726
$_$;
1727

    
1728

    
1729
--
1730
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1731
--
1732

    
1733
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1734
    LANGUAGE plpgsql STRICT
1735
    AS $_$
1736
DECLARE
1737
	view_qual_name text = util.qual_name(view_);
1738
BEGIN
1739
	EXECUTE $$
1740
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1741
  RETURNS SETOF $$||view_||$$
1742
  SET enable_sort TO 'off'
1743
  AS
1744
$BODY1$
1745
SELECT * FROM $$||view_qual_name||$$($2, $3)
1746
$BODY1$
1747
  LANGUAGE sql STABLE
1748
  COST 100
1749
  ROWS 1000
1750
;
1751
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1752
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1753
If you want to run EXPLAIN and get expanded output, use the regular subset
1754
function instead. (When a config param is set on a function, EXPLAIN produces
1755
just a function scan.)
1756
';
1757
$$;
1758
END;
1759
$_$;
1760

    
1761

    
1762
--
1763
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1764
--
1765

    
1766
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS 'creates subset function which turns off enable_sort';
1767

    
1768

    
1769
--
1770
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1771
--
1772

    
1773
CREATE FUNCTION name(type regtype) RETURNS text
1774
    LANGUAGE sql STABLE STRICT
1775
    AS $_$
1776
SELECT typname::text FROM pg_type WHERE oid = $1
1777
$_$;
1778

    
1779

    
1780
--
1781
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1782
--
1783

    
1784
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1785
    LANGUAGE sql IMMUTABLE
1786
    AS $_$
1787
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1788
$_$;
1789

    
1790

    
1791
--
1792
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1793
--
1794

    
1795
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1796
    LANGUAGE sql IMMUTABLE
1797
    AS $_$
1798
SELECT $1 IS NOT NULL
1799
$_$;
1800

    
1801

    
1802
--
1803
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1804
--
1805

    
1806
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1807
    LANGUAGE sql IMMUTABLE
1808
    AS $_$
1809
SELECT util.hstore($1, NULL) || '*=>*'
1810
$_$;
1811

    
1812

    
1813
--
1814
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1815
--
1816

    
1817
COMMENT ON FUNCTION nulls_map(nulls text[]) IS 'for use with _map()';
1818

    
1819

    
1820
--
1821
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1822
--
1823

    
1824
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1825
    LANGUAGE sql IMMUTABLE
1826
    AS $_$
1827
SELECT $2 + COALESCE($1, 0)
1828
$_$;
1829

    
1830

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

    
1835
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1836
    LANGUAGE sql STABLE
1837
    AS $_$
1838
SELECT util.type_qual_name($1::text::regtype)
1839
$_$;
1840

    
1841

    
1842
--
1843
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1844
--
1845

    
1846
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1847
    LANGUAGE plpgsql IMMUTABLE STRICT
1848
    AS $$
1849
BEGIN
1850
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1851
END;
1852
$$;
1853

    
1854

    
1855
--
1856
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
1857
--
1858

    
1859
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
1860
    LANGUAGE sql IMMUTABLE
1861
    AS $_$
1862
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
1863
$_$;
1864

    
1865

    
1866
--
1867
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1868
--
1869

    
1870
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1871
    LANGUAGE sql STRICT
1872
    AS $_$
1873
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1874
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1875
FROM util.col_names($1::text::regtype) f (name);
1876
SELECT NULL::void; -- don't fold away functions called in previous query
1877
$_$;
1878

    
1879

    
1880
--
1881
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1882
--
1883

    
1884
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1885

    
1886

    
1887
--
1888
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1889
--
1890

    
1891
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1892
    LANGUAGE sql STRICT
1893
    AS $_$
1894
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
1895
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1896
SELECT util.set_col_names($1, $2);
1897
$_$;
1898

    
1899

    
1900
--
1901
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1902
--
1903

    
1904
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS 'idempotent.
1905
alters the names table, so it will need to be repopulated after running this function.';
1906

    
1907

    
1908
--
1909
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1910
--
1911

    
1912
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1913
    LANGUAGE sql STRICT
1914
    AS $_$
1915
SELECT util.drop_table($1);
1916
SELECT util.mk_map_table($1);
1917
$_$;
1918

    
1919

    
1920
--
1921
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1922
--
1923

    
1924
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
1925
    LANGUAGE plpgsql STRICT
1926
    AS $_$
1927
DECLARE
1928
	result text = NULL;
1929
BEGIN
1930
	BEGIN
1931
		result = util.show_create_view(view_);
1932
		PERFORM util.eval($$DROP VIEW $$||view_);
1933
	EXCEPTION
1934
		WHEN undefined_table THEN NULL;
1935
	END;
1936
	RETURN result;
1937
END;
1938
$_$;
1939

    
1940

    
1941
--
1942
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
1943
--
1944

    
1945
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
1946
    LANGUAGE sql
1947
    AS $_$
1948
SELECT concat(util.save_drop_view(unnest)) FROM unnest($1)
1949
$_$;
1950

    
1951

    
1952
--
1953
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
1954
--
1955

    
1956
CREATE FUNCTION schema(type regtype) RETURNS text
1957
    LANGUAGE sql STABLE
1958
    AS $_$
1959
SELECT nspname::text
1960
FROM pg_type
1961
JOIN pg_namespace ON pg_namespace.oid = typnamespace
1962
WHERE pg_type.oid = $1
1963
$_$;
1964

    
1965

    
1966
--
1967
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1968
--
1969

    
1970
CREATE FUNCTION schema(type_null anyelement) RETURNS text
1971
    LANGUAGE sql STABLE
1972
    AS $_$
1973
SELECT util.schema(pg_typeof($1))
1974
$_$;
1975

    
1976

    
1977
--
1978
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
1979
--
1980

    
1981
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
1982
    LANGUAGE sql STABLE
1983
    AS $_$
1984
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
1985
$_$;
1986

    
1987

    
1988
--
1989
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
1990
--
1991

    
1992
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS 'a schema bundle is a group of schemas with a common prefix';
1993

    
1994

    
1995
--
1996
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
1997
--
1998

    
1999
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2000
    LANGUAGE sql
2001
    AS $_$
2002
SELECT util.schema_rename(old_schema,
2003
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2004
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2005
SELECT NULL::void; -- don't fold away functions called in previous query
2006
$_$;
2007

    
2008

    
2009
--
2010
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2011
--
2012

    
2013
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2014
    LANGUAGE plpgsql
2015
    AS $$
2016
BEGIN
2017
	-- don't schema_bundle_rm() the schema_bundle to keep!
2018
	IF replace = with_ THEN RETURN; END IF;
2019
	
2020
	PERFORM util.schema_bundle_rm(replace);
2021
	PERFORM util.schema_bundle_rename(with_, replace);
2022
END;
2023
$$;
2024

    
2025

    
2026
--
2027
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2028
--
2029

    
2030
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2031
    LANGUAGE sql
2032
    AS $_$
2033
SELECT util.schema_rm(schema)
2034
FROM util.schema_bundle_get_schemas($1) f (schema);
2035
SELECT NULL::void; -- don't fold away functions called in previous query
2036
$_$;
2037

    
2038

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

    
2043
CREATE FUNCTION schema_ident(type_null anyelement) RETURNS text
2044
    LANGUAGE sql STABLE
2045
    AS $_$
2046
SELECT quote_ident(util.schema($1))
2047
$_$;
2048

    
2049

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

    
2054
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2055
    LANGUAGE sql
2056
    AS $_$
2057
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2058
$_$;
2059

    
2060

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

    
2065
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2066
    LANGUAGE plpgsql
2067
    AS $$
2068
BEGIN
2069
	-- don't schema_rm() the schema to keep!
2070
	IF replace = with_ THEN RETURN; END IF;
2071
	
2072
	PERFORM util.schema_rm(replace);
2073
	PERFORM util.schema_rename(with_, replace);
2074
END;
2075
$$;
2076

    
2077

    
2078
--
2079
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2080
--
2081

    
2082
CREATE FUNCTION schema_rm(schema text) RETURNS void
2083
    LANGUAGE sql
2084
    AS $_$
2085
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2086
$_$;
2087

    
2088

    
2089
--
2090
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2091
--
2092

    
2093
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2094
    LANGUAGE sql STRICT
2095
    AS $_$
2096
SELECT util.eval(
2097
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2098
$_$;
2099

    
2100

    
2101
--
2102
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2103
--
2104

    
2105
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2106
    LANGUAGE plpgsql STRICT
2107
    AS $_$
2108
DECLARE
2109
    old text[] = ARRAY(SELECT util.col_names(table_));
2110
    new text[] = ARRAY(SELECT util.map_values(names));
2111
BEGIN
2112
    old = old[1:array_length(new, 1)]; -- truncate to same length
2113
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2114
||$$ TO $$||quote_ident(value))
2115
    FROM each(hstore(old, new))
2116
    WHERE value != key -- not same name
2117
    ;
2118
END;
2119
$_$;
2120

    
2121

    
2122
--
2123
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2124
--
2125

    
2126
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
2127

    
2128

    
2129
--
2130
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2131
--
2132

    
2133
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2134
    LANGUAGE plpgsql STRICT
2135
    AS $_$
2136
DECLARE
2137
	row_ util.map;
2138
BEGIN
2139
	-- rename any metadata cols rather than re-adding them with new names
2140
	BEGIN
2141
		PERFORM util.set_col_names(table_, names);
2142
	EXCEPTION
2143
		WHEN array_subscript_error THEN -- selective suppress
2144
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2145
				-- metadata cols not yet added
2146
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2147
			END IF;
2148
	END;
2149
	
2150
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2151
	LOOP
2152
		PERFORM util.mk_const_col((table_, row_."to"),
2153
			substring(row_."from" from 2));
2154
	END LOOP;
2155
	
2156
	PERFORM util.set_col_names(table_, names);
2157
END;
2158
$_$;
2159

    
2160

    
2161
--
2162
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2163
--
2164

    
2165
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS 'idempotent.
2166
the metadata mappings must be *last* in the names table.';
2167

    
2168

    
2169
--
2170
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2171
--
2172

    
2173
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2174
    LANGUAGE plpgsql STRICT
2175
    AS $_$
2176
DECLARE
2177
    sql text = $$ALTER TABLE $$||table_||$$
2178
$$||NULLIF(array_to_string(ARRAY(
2179
    SELECT
2180
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2181
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2182
    FROM
2183
    (
2184
        SELECT
2185
          quote_ident(col_name) AS col_name_sql
2186
        , util.col_type((table_, col_name)) AS curr_type
2187
        , type AS target_type
2188
        FROM unnest(col_casts)
2189
    ) s
2190
    WHERE curr_type != target_type
2191
), '
2192
, '), '');
2193
BEGIN
2194
    RAISE NOTICE '%', sql;
2195
    EXECUTE COALESCE(sql, '');
2196
END;
2197
$_$;
2198

    
2199

    
2200
--
2201
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2202
--
2203

    
2204
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS 'idempotent';
2205

    
2206

    
2207
--
2208
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2209
--
2210

    
2211
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2212
    LANGUAGE sql STABLE
2213
    AS $_$
2214
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2215
$$||util.show_grants_for($1)
2216
$_$;
2217

    
2218

    
2219
--
2220
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2221
--
2222

    
2223
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2224
    LANGUAGE sql STABLE
2225
    AS $_$
2226
SELECT concat(cmd)
2227
FROM
2228
(
2229
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2230
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2231
$$ ELSE '' END) AS cmd
2232
	FROM util.grants_users() f (user_)
2233
) s
2234
$_$;
2235

    
2236

    
2237
--
2238
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2239
--
2240

    
2241
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2242
    LANGUAGE plpgsql STABLE STRICT
2243
    AS $_$
2244
DECLARE
2245
    hstore hstore;
2246
BEGIN
2247
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2248
        table_||$$))$$ INTO STRICT hstore;
2249
    RETURN hstore;
2250
END;
2251
$_$;
2252

    
2253

    
2254
--
2255
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2256
--
2257

    
2258
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2259
    LANGUAGE sql STABLE STRICT
2260
    AS $_$
2261
SELECT COUNT(*) > 0 FROM pg_constraint
2262
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2263
$_$;
2264

    
2265

    
2266
--
2267
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2268
--
2269

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

    
2272

    
2273
--
2274
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2275
--
2276

    
2277
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2278
    LANGUAGE sql STRICT
2279
    AS $_$
2280
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2281
||quote_ident($2)||$$ CHECK (true)$$)
2282
$_$;
2283

    
2284

    
2285
--
2286
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2287
--
2288

    
2289
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS 'stores a status flag by the presence of a table constraint.
2290
idempotent.';
2291

    
2292

    
2293
--
2294
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2295
--
2296

    
2297
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2298
    LANGUAGE sql STABLE STRICT
2299
    AS $_$
2300
SELECT util.table_flag__get($1, 'nulls_mapped')
2301
$_$;
2302

    
2303

    
2304
--
2305
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2306
--
2307

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

    
2310

    
2311
--
2312
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2313
--
2314

    
2315
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2316
    LANGUAGE sql STRICT
2317
    AS $_$
2318
SELECT util.table_flag__set($1, 'nulls_mapped')
2319
$_$;
2320

    
2321

    
2322
--
2323
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2324
--
2325

    
2326
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS 'sets that a table''s NULL-equivalent strings have been replaced with NULL.
2327
idempotent.';
2328

    
2329

    
2330
--
2331
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2332
--
2333

    
2334
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
2335
    LANGUAGE sql STABLE STRICT
2336
    AS $_$
2337
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
2338
$_$;
2339

    
2340

    
2341
--
2342
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2343
--
2344

    
2345
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2346
    LANGUAGE plpgsql STRICT
2347
    AS $_$
2348
DECLARE
2349
    row record;
2350
BEGIN
2351
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2352
    LOOP
2353
        IF row.global_name != row.name THEN
2354
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2355
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2356
        END IF;
2357
    END LOOP;
2358
END;
2359
$_$;
2360

    
2361

    
2362
--
2363
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2364
--
2365

    
2366
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
2367

    
2368

    
2369
--
2370
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2371
--
2372

    
2373
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2374
    LANGUAGE sql STRICT
2375
    AS $_$
2376
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2377
SELECT NULL::void; -- don't fold away functions called in previous query
2378
$_$;
2379

    
2380

    
2381
--
2382
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2383
--
2384

    
2385
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS 'trims table_ to include only columns in the original data.
2386
idempotent.';
2387

    
2388

    
2389
--
2390
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2391
--
2392

    
2393
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2394
    LANGUAGE plpgsql STRICT
2395
    AS $_$
2396
BEGIN
2397
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2398
END;
2399
$_$;
2400

    
2401

    
2402
--
2403
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2404
--
2405

    
2406
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
2407

    
2408

    
2409
--
2410
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2411
--
2412

    
2413
CREATE FUNCTION try_create(sql text) RETURNS void
2414
    LANGUAGE plpgsql STRICT
2415
    AS $$
2416
BEGIN
2417
    PERFORM util.eval(sql);
2418
EXCEPTION
2419
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2420
    WHEN undefined_column THEN NULL;
2421
    WHEN duplicate_column THEN NULL;
2422
END;
2423
$$;
2424

    
2425

    
2426
--
2427
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2428
--
2429

    
2430
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
2431

    
2432

    
2433
--
2434
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2435
--
2436

    
2437
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2438
    LANGUAGE sql STRICT
2439
    AS $_$
2440
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2441
$_$;
2442

    
2443

    
2444
--
2445
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2446
--
2447

    
2448
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
2449

    
2450

    
2451
--
2452
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2453
--
2454

    
2455
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2456
    LANGUAGE sql IMMUTABLE
2457
    AS $_$
2458
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2459
$_$;
2460

    
2461

    
2462
--
2463
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2464
--
2465

    
2466
COMMENT ON FUNCTION type_qual(value anyelement) IS 'a type''s NOT NULL qualifier';
2467

    
2468

    
2469
--
2470
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2471
--
2472

    
2473
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
2474
    LANGUAGE sql STABLE STRICT
2475
    SET search_path TO pg_temp
2476
    AS $_$
2477
SELECT $1::text
2478
$_$;
2479

    
2480

    
2481
--
2482
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2483
--
2484

    
2485
COMMENT ON FUNCTION type_qual_name(type regtype) IS 'a type''s schema-qualified name';
2486

    
2487

    
2488
--
2489
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2490
--
2491

    
2492
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2493
    LANGUAGE plpgsql STABLE
2494
    AS $_$
2495
DECLARE
2496
    type regtype;
2497
BEGIN
2498
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2499
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2500
    RETURN type;
2501
END;
2502
$_$;
2503

    
2504

    
2505
--
2506
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2507
--
2508

    
2509
CREATE AGGREGATE all_same(anyelement) (
2510
    SFUNC = all_same_transform,
2511
    STYPE = anyarray,
2512
    FINALFUNC = all_same_final
2513
);
2514

    
2515

    
2516
--
2517
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2518
--
2519

    
2520
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
2521

    
2522

    
2523
--
2524
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2525
--
2526

    
2527
CREATE AGGREGATE join_strs(text, text) (
2528
    SFUNC = join_strs_transform,
2529
    STYPE = text
2530
);
2531

    
2532

    
2533
--
2534
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2535
--
2536

    
2537
CREATE OPERATOR -> (
2538
    PROCEDURE = map_get,
2539
    LEFTARG = regclass,
2540
    RIGHTARG = text
2541
);
2542

    
2543

    
2544
--
2545
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2546
--
2547

    
2548
CREATE OPERATOR => (
2549
    PROCEDURE = hstore,
2550
    LEFTARG = text[],
2551
    RIGHTARG = text
2552
);
2553

    
2554

    
2555
--
2556
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2557
--
2558

    
2559
COMMENT ON OPERATOR => (text[], text) IS 'usage: array[''key1'', ...]::text[] => ''value''';
2560

    
2561

    
2562
--
2563
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2564
--
2565

    
2566
CREATE OPERATOR ?*>= (
2567
    PROCEDURE = is_populated_more_often_than,
2568
    LEFTARG = anyelement,
2569
    RIGHTARG = anyelement
2570
);
2571

    
2572

    
2573
--
2574
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2575
--
2576

    
2577
CREATE OPERATOR ?>= (
2578
    PROCEDURE = is_more_complete_than,
2579
    LEFTARG = anyelement,
2580
    RIGHTARG = anyelement
2581
);
2582

    
2583

    
2584
--
2585
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2586
--
2587

    
2588
CREATE OPERATOR ||% (
2589
    PROCEDURE = concat_esc,
2590
    LEFTARG = text,
2591
    RIGHTARG = text
2592
);
2593

    
2594

    
2595
--
2596
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2597
--
2598

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

    
2601

    
2602
--
2603
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2604
--
2605

    
2606
CREATE TABLE map (
2607
    "from" text NOT NULL,
2608
    "to" text,
2609
    filter text,
2610
    notes text
2611
);
2612

    
2613

    
2614
--
2615
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2616
--
2617

    
2618

    
2619

    
2620
--
2621
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2622
--
2623

    
2624

    
2625

    
2626
--
2627
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2628
--
2629

    
2630
ALTER TABLE ONLY map
2631
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2632

    
2633

    
2634
--
2635
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2636
--
2637

    
2638
ALTER TABLE ONLY map
2639
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2640

    
2641

    
2642
--
2643
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2644
--
2645

    
2646
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2647

    
2648

    
2649
--
2650
-- PostgreSQL database dump complete
2651
--
2652

    
(19-19/29)