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: 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.
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: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77

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

    
84

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

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

    
104

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

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

    
113

    
114
--
115
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
116
--
117

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

    
133

    
134
--
135
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
136
--
137

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

    
152

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

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

    
170

    
171
--
172
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
173
--
174

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

    
181

    
182
--
183
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
184
--
185

    
186
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
187
    LANGUAGE sql IMMUTABLE
188
    AS $_$
189
SELECT $1 = $2
190
$_$;
191

    
192

    
193
--
194
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
195
--
196

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

    
205

    
206
--
207
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
208
--
209

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

    
216

    
217
--
218
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
219
--
220

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

    
227

    
228
--
229
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
230
--
231

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

    
238

    
239
--
240
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
241
--
242

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

    
249

    
250
--
251
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
252
--
253

    
254
CREATE FUNCTION _label(label text, value text) RETURNS text
255
    LANGUAGE sql IMMUTABLE
256
    AS $_$
257
SELECT coalesce($1 || ': ', '') || $2
258
$_$;
259

    
260

    
261
--
262
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
263
--
264

    
265
CREATE FUNCTION _lowercase(value text) RETURNS text
266
    LANGUAGE sql IMMUTABLE
267
    AS $_$
268
SELECT lower($1)
269
$_$;
270

    
271

    
272
--
273
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
274
--
275

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

    
286

    
287
--
288
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
289
--
290

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

    
311

    
312
--
313
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
314
--
315

    
316
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
317
    LANGUAGE sql IMMUTABLE
318
    AS $_$
319
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
320
$_$;
321

    
322

    
323
--
324
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
325
--
326

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

    
361

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

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

    
372

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

    
377
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
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: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
414
--
415

    
416
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
417
    LANGUAGE sql IMMUTABLE
418
    AS $_$
419
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
420
$_$;
421

    
422

    
423
--
424
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
425
--
426

    
427
CREATE FUNCTION _not(value boolean) RETURNS boolean
428
    LANGUAGE sql IMMUTABLE
429
    AS $_$
430
SELECT NOT $1
431
$_$;
432

    
433

    
434
--
435
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
436
--
437

    
438
CREATE FUNCTION _now() RETURNS timestamp with time zone
439
    LANGUAGE sql STABLE
440
    AS $$
441
SELECT now()
442
$$;
443

    
444

    
445
--
446
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
447
--
448

    
449
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
450
    LANGUAGE sql IMMUTABLE
451
    AS $_$
452
SELECT util."_nullIf"($1, $2, $3::util.datatype)
453
$_$;
454

    
455

    
456
--
457
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
458
--
459

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

    
481

    
482
--
483
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
484
--
485

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

    
501

    
502
--
503
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
504
--
505

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

    
510

    
511
--
512
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
513
--
514

    
515
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
516
    LANGUAGE sql IMMUTABLE
517
    AS $_$
518
SELECT $2 - $1
519
$_$;
520

    
521

    
522
--
523
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
524
--
525

    
526
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
527
    LANGUAGE sql IMMUTABLE
528
    AS $_$
529
SELECT regexp_split_to_table($1, $2)
530
$_$;
531

    
532

    
533
--
534
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
535
--
536

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

    
550

    
551
--
552
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
553
--
554

    
555
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
556
gets table_''s added columns (all the columns not in the original data)
557
';
558

    
559

    
560
--
561
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
562
--
563

    
564
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
565
    LANGUAGE sql IMMUTABLE
566
    AS $_$
567
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
568
$_$;
569

    
570

    
571
--
572
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
573
--
574

    
575
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
576
    LANGUAGE plpgsql IMMUTABLE
577
    AS $$
578
DECLARE
579
	value_cmp         state%TYPE = ARRAY[value];
580
	state             state%TYPE = COALESCE(state, value_cmp);
581
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
582
BEGIN
583
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
584
END;
585
$$;
586

    
587

    
588
--
589
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
590
--
591

    
592
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
593
    LANGUAGE sql IMMUTABLE
594
    AS $_$
595
SELECT pg_catalog.array_fill($1, ARRAY[$2])
596
$_$;
597

    
598

    
599
--
600
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
601
--
602

    
603
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
604
    LANGUAGE sql IMMUTABLE
605
    AS $_$
606
SELECT util.array_length($1, 1)
607
$_$;
608

    
609

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

    
614
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
615
    LANGUAGE sql IMMUTABLE
616
    AS $_$
617
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
618
$_$;
619

    
620

    
621
--
622
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
623
--
624

    
625
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
626
returns 0 instead of NULL for empty arrays
627
';
628

    
629

    
630
--
631
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
632
--
633

    
634
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
635
    LANGUAGE sql STABLE STRICT
636
    AS $_$
637
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
638
$_$;
639

    
640

    
641
--
642
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
643
--
644

    
645
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
646
    LANGUAGE plpgsql STRICT
647
    AS $_$
648
BEGIN
649
    -- not yet clustered (ARRAY[] compares NULLs literally)
650
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
651
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
652
    END IF;
653
END;
654
$_$;
655

    
656

    
657
--
658
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
659
--
660

    
661
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
662
idempotent
663
';
664

    
665

    
666
--
667
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
668
--
669

    
670
CREATE FUNCTION col__min(col col_ref) RETURNS integer
671
    LANGUAGE sql STABLE
672
    AS $_$
673
SELECT util.eval2val($$
674
SELECT $$||quote_ident($1.name)||$$
675
FROM $$||$1.table_||$$
676
ORDER BY $$||quote_ident($1.name)||$$ ASC
677
LIMIT 1
678
$$, NULL::integer)
679
$_$;
680

    
681

    
682
--
683
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
684
--
685

    
686
CREATE FUNCTION col_comment(col col_ref) RETURNS text
687
    LANGUAGE plpgsql STABLE STRICT
688
    AS $$
689
DECLARE
690
	comment text;
691
BEGIN
692
	SELECT description
693
	FROM pg_attribute
694
	LEFT JOIN pg_description ON objoid = attrelid
695
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
696
	WHERE attrelid = col.table_ AND attname = col.name
697
	INTO STRICT comment
698
	;
699
	RETURN comment;
700
EXCEPTION
701
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
702
END;
703
$$;
704

    
705

    
706
--
707
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
708
--
709

    
710
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
711
    LANGUAGE plpgsql STABLE STRICT
712
    AS $$
713
DECLARE
714
	default_sql text;
715
BEGIN
716
	SELECT adsrc
717
	FROM pg_attribute
718
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
719
	WHERE attrelid = col.table_ AND attname = col.name
720
	INTO STRICT default_sql
721
	;
722
	RETURN default_sql;
723
EXCEPTION
724
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
725
END;
726
$$;
727

    
728

    
729
--
730
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
731
--
732

    
733
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
734
    LANGUAGE sql STABLE
735
    AS $_$
736
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
737
$_$;
738

    
739

    
740
--
741
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
742
--
743

    
744
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
745
ret_type_null: NULL::ret_type
746
';
747

    
748

    
749
--
750
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
751
--
752

    
753
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
754
    LANGUAGE plpgsql STRICT
755
    AS $$
756
BEGIN
757
    PERFORM util.col_type(col);
758
    RETURN true;
759
EXCEPTION
760
    WHEN undefined_column THEN RETURN false;
761
END;
762
$$;
763

    
764

    
765
--
766
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
767
--
768

    
769
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
770
    LANGUAGE plpgsql STABLE STRICT
771
    AS $$
772
DECLARE
773
    prefix text := util.name(type)||'.';
774
BEGIN
775
    RETURN QUERY
776
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
777
        FROM util.col_names(type) f (name_);
778
END;
779
$$;
780

    
781

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

    
786
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
787
    LANGUAGE sql STABLE STRICT
788
    AS $_$
789
SELECT attname::text
790
FROM pg_attribute
791
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
792
ORDER BY attnum
793
$_$;
794

    
795

    
796
--
797
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
798
--
799

    
800
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
801
    LANGUAGE plpgsql STABLE STRICT
802
    AS $_$
803
BEGIN
804
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
805
END;
806
$_$;
807

    
808

    
809
--
810
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
811
--
812

    
813
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
814
    LANGUAGE plpgsql STABLE STRICT
815
    AS $$
816
DECLARE
817
    type regtype;
818
BEGIN
819
    SELECT atttypid FROM pg_attribute
820
    WHERE attrelid = col.table_ AND attname = col.name
821
    INTO STRICT type
822
    ;
823
    RETURN type;
824
EXCEPTION
825
    WHEN no_data_found THEN
826
        RAISE undefined_column USING MESSAGE =
827
            concat('undefined column: ', col.name);
828
END;
829
$$;
830

    
831

    
832
--
833
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
834
--
835

    
836
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
837
    LANGUAGE sql IMMUTABLE
838
    AS $_$
839
SELECT util.esc_name__append($2, $1)
840
$_$;
841

    
842

    
843
--
844
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
845
--
846

    
847
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
848
    LANGUAGE sql IMMUTABLE
849
    AS $_$
850
SELECT position($1 in $2) > 0 /*1-based offset*/
851
$_$;
852

    
853

    
854
--
855
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
856
--
857

    
858
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
859
    LANGUAGE plpgsql STRICT
860
    AS $$
861
BEGIN
862
    PERFORM util.eval(sql);
863
EXCEPTION
864
    WHEN duplicate_table  THEN NULL;
865
    WHEN duplicate_object THEN NULL; -- e.g. constraint
866
    WHEN duplicate_column THEN NULL;
867
    WHEN invalid_table_definition THEN
868
        IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
869
        ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
870
        END IF;
871
END;
872
$$;
873

    
874

    
875
--
876
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
877
--
878

    
879
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
880
idempotent
881
';
882

    
883

    
884
--
885
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
886
--
887

    
888
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
889
    LANGUAGE sql IMMUTABLE
890
    AS $_$
891
/* newline before so the query starts at the beginning of the line.
892
newline after to visually separate queries from one another. */
893
SELECT util.raise_notice($$
894
$$||$1||$$
895
$$)
896
$_$;
897

    
898

    
899
--
900
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
901
--
902

    
903
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
904
    LANGUAGE sql STABLE STRICT
905
    AS $_$
906
SELECT util.eval2set($$
907
SELECT col
908
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
909
LEFT JOIN $$||$2||$$ ON "to" = col
910
WHERE "from" IS NULL
911
$$, NULL::text)
912
$_$;
913

    
914

    
915
--
916
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
917
--
918

    
919
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
920
gets table_''s derived columns (all the columns not in the names table)
921
';
922

    
923

    
924
--
925
-- Name: diff_cols(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
926
--
927

    
928
CREATE FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
929
    LANGUAGE sql STABLE
930
    AS $_$
931
SELECT * FROM
932
util.eval2col_pair($$
933
SELECT * FROM
934
(
935
$$||$1||$$
936
) left_ (left_)
937
FULL JOIN
938
(
939
$$||$2||$$
940
) right_ (right_)
941
ON left_ = right_
942
WHERE left_ IS DISTINCT FROM right_
943
ORDER BY left_, right_
944
$$, $3)
945
$_$;
946

    
947

    
948
--
949
-- 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: -
950
--
951

    
952
COMMENT ON FUNCTION diff_cols(left_query text, right_query text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
953
col_type_null (*required*): NULL::col_type
954
usage:
955
SELECT * FROM util.diff_cols($$VALUES (''1''), (''2''), (''4'')$$, $$VALUES (''1''), (''3''), (''4'')$$, NULL::text)
956

    
957
to run EXPLAIN on the FULL JOIN query:
958
# run this function
959
# look for a NOTICE containing the expanded query that it ran
960
# run EXPLAIN on this expanded query
961
';
962

    
963

    
964
--
965
-- Name: diff_views(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
966
--
967

    
968
CREATE FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
969
    LANGUAGE sql STABLE
970
    AS $_$
971
SELECT * FROM util.diff_cols($$SELECT * FROM $$||$1, $$SELECT * FROM $$||$1, $3)
972
$_$;
973

    
974

    
975
--
976
-- 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: -
977
--
978

    
979
COMMENT ON FUNCTION diff_views(left_view regclass, right_view regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
980
col_type_null (*required*): NULL::col_type
981
usage:
982
SELECT * FROM util.diff_views(''"left_view"'', ''"right_view"'', NULL::text)
983
';
984

    
985

    
986
--
987
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
988
--
989

    
990
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
991
    LANGUAGE sql STRICT
992
    AS $_$
993
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
994
$_$;
995

    
996

    
997
--
998
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
999
--
1000

    
1001
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1002
idempotent
1003
';
1004

    
1005

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

    
1010
CREATE FUNCTION drop_column(col col_ref) RETURNS void
1011
    LANGUAGE sql STRICT
1012
    AS $_$
1013
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1014
quote_ident($1.name))
1015
$_$;
1016

    
1017

    
1018
--
1019
-- Name: FUNCTION drop_column(col col_ref); Type: COMMENT; Schema: util; Owner: -
1020
--
1021

    
1022
COMMENT ON FUNCTION drop_column(col col_ref) IS '
1023
idempotent
1024
';
1025

    
1026

    
1027
--
1028
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
1029
--
1030

    
1031
CREATE FUNCTION drop_table(table_ text) RETURNS void
1032
    LANGUAGE sql STRICT
1033
    AS $_$
1034
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
1035
$_$;
1036

    
1037

    
1038
--
1039
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
1040
--
1041

    
1042
COMMENT ON FUNCTION drop_table(table_ text) IS '
1043
idempotent
1044
';
1045

    
1046

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

    
1051
CREATE FUNCTION drop_view(view_ text) RETURNS void
1052
    LANGUAGE sql STRICT
1053
    AS $_$
1054
SELECT util.eval($$DROP VIEW IF EXISTS $$||$1)
1055
$_$;
1056

    
1057

    
1058
--
1059
-- Name: FUNCTION drop_view(view_ text); Type: COMMENT; Schema: util; Owner: -
1060
--
1061

    
1062
COMMENT ON FUNCTION drop_view(view_ text) IS '
1063
idempotent
1064
';
1065

    
1066

    
1067
--
1068
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1069
--
1070

    
1071
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1072
    LANGUAGE sql IMMUTABLE
1073
    AS $_$
1074
SELECT util.array_fill($1, 0)
1075
$_$;
1076

    
1077

    
1078
--
1079
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1080
--
1081

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

    
1086

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

    
1091
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1092
    LANGUAGE sql IMMUTABLE
1093
    AS $_$
1094
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1095
$_$;
1096

    
1097

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

    
1102
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1103
    LANGUAGE sql IMMUTABLE
1104
    AS $_$
1105
SELECT regexp_replace($2, '("?)$', $1||'\1')
1106
$_$;
1107

    
1108

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

    
1113
CREATE FUNCTION eval(sql text) RETURNS void
1114
    LANGUAGE plpgsql STRICT
1115
    AS $$
1116
BEGIN
1117
	PERFORM util.debug_print_sql(sql);
1118
	EXECUTE sql;
1119
END;
1120
$$;
1121

    
1122

    
1123
--
1124
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1125
--
1126

    
1127
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1128
    LANGUAGE plpgsql
1129
    AS $$
1130
BEGIN
1131
	PERFORM util.debug_print_sql(sql);
1132
	RETURN QUERY EXECUTE sql;
1133
END;
1134
$$;
1135

    
1136

    
1137
--
1138
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1139
--
1140

    
1141
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1142
col_type_null (*required*): NULL::col_type
1143
';
1144

    
1145

    
1146
--
1147
-- Name: eval2set(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1148
--
1149

    
1150
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1151
    LANGUAGE plpgsql
1152
    AS $$
1153
BEGIN
1154
	PERFORM util.debug_print_sql(sql);
1155
	RETURN QUERY EXECUTE sql;
1156
END;
1157
$$;
1158

    
1159

    
1160
--
1161
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1162
--
1163

    
1164
COMMENT ON FUNCTION eval2set(sql text, ret_type_null anyelement) IS '
1165
ret_type_null: NULL::ret_type
1166
';
1167

    
1168

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

    
1173
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1174
    LANGUAGE plpgsql
1175
    AS $$
1176
DECLARE
1177
	ret_val ret_type_null%TYPE;
1178
BEGIN
1179
	PERFORM util.debug_print_sql(sql);
1180
	EXECUTE sql INTO STRICT ret_val;
1181
	RETURN ret_val;
1182
END;
1183
$$;
1184

    
1185

    
1186
--
1187
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1188
--
1189

    
1190
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1191
ret_type_null: NULL::ret_type
1192
';
1193

    
1194

    
1195
--
1196
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1197
--
1198

    
1199
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1200
    LANGUAGE sql
1201
    AS $_$
1202
SELECT util.eval2val($$SELECT $$||$1, $2)
1203
$_$;
1204

    
1205

    
1206
--
1207
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1208
--
1209

    
1210
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1211
ret_type_null: NULL::ret_type
1212
';
1213

    
1214

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

    
1219
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1220
    LANGUAGE sql
1221
    AS $_$
1222
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1223
$_$;
1224

    
1225

    
1226
--
1227
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1228
--
1229

    
1230
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1231
sql: can be NULL, which will be passed through
1232
ret_type_null: NULL::ret_type
1233
';
1234

    
1235

    
1236
--
1237
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1238
--
1239

    
1240
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1241
    LANGUAGE sql STABLE STRICT
1242
    AS $_$
1243
SELECT col_name
1244
FROM unnest($2) s (col_name)
1245
WHERE util.col_exists(($1, col_name))
1246
$_$;
1247

    
1248

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

    
1253
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1254
    LANGUAGE sql
1255
    AS $_$
1256
SELECT util.eval2set($$EXPLAIN $$||$1)
1257
$_$;
1258

    
1259

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

    
1264
CREATE FUNCTION explain2notice(sql text) RETURNS void
1265
    LANGUAGE plpgsql
1266
    AS $_$
1267
BEGIN
1268
	RAISE NOTICE '%', $$EXPLAIN:
1269
$$||util.explain2str(sql);
1270
END;
1271
$_$;
1272

    
1273

    
1274
--
1275
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1276
--
1277

    
1278
CREATE FUNCTION explain2str(sql text) RETURNS text
1279
    LANGUAGE sql
1280
    AS $_$
1281
SELECT util.join_strs(explain, $$
1282
$$) FROM util.explain($1)
1283
$_$;
1284

    
1285

    
1286
SET default_tablespace = '';
1287

    
1288
SET default_with_oids = false;
1289

    
1290
--
1291
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1292
--
1293

    
1294
CREATE TABLE explain (
1295
    line text NOT NULL
1296
);
1297

    
1298

    
1299
--
1300
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1301
--
1302

    
1303
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1304
    LANGUAGE sql
1305
    AS $_$
1306
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1307
$$||quote_nullable($1)||$$
1308
)$$)
1309
$_$;
1310

    
1311

    
1312
--
1313
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1314
--
1315

    
1316
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1317
usage:
1318
PERFORM util.explain2table($$
1319
query
1320
$$);
1321
';
1322

    
1323

    
1324
--
1325
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1326
--
1327

    
1328
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1329
    LANGUAGE sql IMMUTABLE
1330
    AS $_$
1331
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1332
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1333
) END
1334
$_$;
1335

    
1336

    
1337
--
1338
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1339
--
1340

    
1341
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1342
ensures that an array will always have proper non-NULL dimensions
1343
';
1344

    
1345

    
1346
--
1347
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1348
--
1349

    
1350
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1351
    LANGUAGE plpgsql
1352
    AS $_$
1353
DECLARE
1354
	PG_EXCEPTION_DETAIL text;
1355
	recreate_users_cmd text = util.save_drop_views(users);
1356
BEGIN
1357
	PERFORM util.eval(cmd);
1358
	PERFORM util.eval(recreate_users_cmd);
1359
EXCEPTION
1360
WHEN dependent_objects_still_exist THEN
1361
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1362
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1363
	users = array(SELECT * FROM util.regexp_matches_group(
1364
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1365
	IF util.is_empty(users) THEN RAISE; END IF;
1366
	PERFORM util.force_recreate(cmd, users);
1367
END;
1368
$_$;
1369

    
1370

    
1371
--
1372
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1373
--
1374

    
1375
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1376
idempotent
1377

    
1378
users: not necessary to provide this because it will be autopopulated
1379
';
1380

    
1381

    
1382
--
1383
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1384
--
1385

    
1386
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1387
    LANGUAGE plpgsql STRICT
1388
    AS $_$
1389
DECLARE
1390
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1391
$$||query;
1392
BEGIN
1393
	EXECUTE mk_view;
1394
EXCEPTION
1395
WHEN invalid_table_definition THEN
1396
	IF SQLERRM = 'cannot drop columns from view'
1397
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1398
	THEN
1399
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1400
		EXECUTE mk_view;
1401
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1402
	END IF;
1403
END;
1404
$_$;
1405

    
1406

    
1407
--
1408
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1409
--
1410

    
1411
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1412
idempotent
1413
';
1414

    
1415

    
1416
--
1417
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1418
--
1419

    
1420
CREATE FUNCTION grants_users() RETURNS SETOF text
1421
    LANGUAGE sql IMMUTABLE
1422
    AS $$
1423
VALUES ('bien_read'), ('public_')
1424
$$;
1425

    
1426

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

    
1431
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1432
    LANGUAGE sql IMMUTABLE
1433
    AS $_$
1434
SELECT substring($2 for length($1)) = $1
1435
$_$;
1436

    
1437

    
1438
--
1439
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1440
--
1441

    
1442
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1443
    LANGUAGE sql IMMUTABLE
1444
    AS $_$
1445
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1446
$_$;
1447

    
1448

    
1449
--
1450
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1451
--
1452

    
1453
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1454
avoids repeating the same value for each key
1455
';
1456

    
1457

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

    
1462
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1463
    LANGUAGE sql IMMUTABLE
1464
    AS $_$
1465
SELECT COALESCE($1, $2)
1466
$_$;
1467

    
1468

    
1469
--
1470
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1471
--
1472

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

    
1477

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

    
1482
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1483
    LANGUAGE sql STABLE STRICT
1484
    AS $_$
1485
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1486
$_$;
1487

    
1488

    
1489
--
1490
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1491
--
1492

    
1493
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1494
    LANGUAGE sql IMMUTABLE
1495
    AS $_$
1496
SELECT util.array_length($1) = 0
1497
$_$;
1498

    
1499

    
1500
--
1501
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1502
--
1503

    
1504
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1505
    LANGUAGE sql IMMUTABLE
1506
    AS $_$
1507
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1508
$_$;
1509

    
1510

    
1511
--
1512
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1513
--
1514

    
1515
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1516
    LANGUAGE sql IMMUTABLE
1517
    AS $_$
1518
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1519
$_$;
1520

    
1521

    
1522
--
1523
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1524
--
1525

    
1526
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1527
    LANGUAGE sql IMMUTABLE STRICT
1528
    AS $_$
1529
SELECT $1 || $3 || $2
1530
$_$;
1531

    
1532

    
1533
--
1534
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1535
--
1536

    
1537
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1538
    LANGUAGE sql IMMUTABLE
1539
    AS $_$
1540
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1541
$_$;
1542

    
1543

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

    
1548
CREATE FUNCTION map_filter_insert() RETURNS trigger
1549
    LANGUAGE plpgsql
1550
    AS $$
1551
BEGIN
1552
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1553
	RETURN new;
1554
END;
1555
$$;
1556

    
1557

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

    
1562
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1563
    LANGUAGE plpgsql STABLE STRICT
1564
    AS $_$
1565
DECLARE
1566
    value text;
1567
BEGIN
1568
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1569
        INTO value USING key;
1570
    RETURN value;
1571
END;
1572
$_$;
1573

    
1574

    
1575
--
1576
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1577
--
1578

    
1579
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1580
    LANGUAGE sql IMMUTABLE
1581
    AS $_$
1582
SELECT util._map(util.nulls_map($1), $2)
1583
$_$;
1584

    
1585

    
1586
--
1587
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1588
--
1589

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

    
1593
[1] inlining of function calls, which is different from constant folding
1594
[2] _map()''s profiling query
1595
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1596
and map_nulls()''s profiling query
1597
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1598
both take ~920 ms.
1599
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.
1600
';
1601

    
1602

    
1603
--
1604
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1605
--
1606

    
1607
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1608
    LANGUAGE plpgsql STABLE STRICT
1609
    AS $_$
1610
BEGIN
1611
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1612
END;
1613
$_$;
1614

    
1615

    
1616
--
1617
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1618
--
1619

    
1620
CREATE FUNCTION materialize_query(table_ text, sql text) RETURNS void
1621
    LANGUAGE sql
1622
    AS $_$
1623
SELECT util.create_if_not_exists($$CREATE TABLE $$||quote_ident($1)||$$ AS
1624
$$||$2)
1625
$_$;
1626

    
1627

    
1628
--
1629
-- Name: FUNCTION materialize_query(table_ text, sql text); Type: COMMENT; Schema: util; Owner: -
1630
--
1631

    
1632
COMMENT ON FUNCTION materialize_query(table_ text, sql text) IS '
1633
idempotent
1634
';
1635

    
1636

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

    
1641
CREATE FUNCTION materialize_view(table_ text, view_ regclass) RETURNS void
1642
    LANGUAGE sql
1643
    AS $_$
1644
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
1645
$_$;
1646

    
1647

    
1648
--
1649
-- Name: FUNCTION materialize_view(table_ text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
1650
--
1651

    
1652
COMMENT ON FUNCTION materialize_view(table_ text, view_ regclass) IS '
1653
idempotent
1654
';
1655

    
1656

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

    
1661
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1662
    LANGUAGE sql STRICT
1663
    AS $_$
1664
SELECT util.create_if_not_exists($$
1665
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1666
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1667
||quote_literal($2)||$$;
1668
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
1669
constant
1670
';
1671
$$)
1672
$_$;
1673

    
1674

    
1675
--
1676
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1677
--
1678

    
1679
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
1680
idempotent
1681
';
1682

    
1683

    
1684
--
1685
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1686
--
1687

    
1688
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1689
    LANGUAGE plpgsql STRICT
1690
    AS $_$
1691
DECLARE
1692
    type regtype = util.typeof(expr, col.table_::text::regtype);
1693
    col_name_sql text = quote_ident(col.name);
1694
BEGIN
1695
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1696
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1697
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1698
$$||expr||$$;
1699
$$);
1700
END;
1701
$_$;
1702

    
1703

    
1704
--
1705
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1706
--
1707

    
1708
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
1709
idempotent
1710
';
1711

    
1712

    
1713
--
1714
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1715
--
1716

    
1717
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1718
    LANGUAGE sql STRICT
1719
    AS $_$
1720
SELECT util.create_if_not_exists($$
1721
CREATE TABLE $$||$1||$$
1722
(
1723
    LIKE util.map INCLUDING ALL
1724
);
1725

    
1726
CREATE TRIGGER map_filter_insert
1727
  BEFORE INSERT
1728
  ON $$||$1||$$
1729
  FOR EACH ROW
1730
  EXECUTE PROCEDURE util.map_filter_insert();
1731
$$)
1732
$_$;
1733

    
1734

    
1735
--
1736
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
1737
--
1738

    
1739
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
1740
    LANGUAGE sql IMMUTABLE
1741
    AS $_$
1742
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1)
1743
$_$;
1744

    
1745

    
1746
--
1747
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1748
--
1749

    
1750
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1751
    LANGUAGE sql STRICT
1752
    AS $_$
1753
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
1754
$_$;
1755

    
1756

    
1757
--
1758
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1759
--
1760

    
1761
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
1762
idempotent
1763
';
1764

    
1765

    
1766
--
1767
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1768
--
1769

    
1770
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1771
    LANGUAGE plpgsql STRICT
1772
    AS $_$
1773
DECLARE
1774
	view_qual_name text = util.qual_name(view_);
1775
BEGIN
1776
	EXECUTE $$
1777
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1778
  RETURNS SETOF $$||view_||$$ AS
1779
$BODY1$
1780
SELECT * FROM $$||view_qual_name||$$
1781
ORDER BY sort_col
1782
LIMIT $1 OFFSET $2
1783
$BODY1$
1784
  LANGUAGE sql STABLE
1785
  COST 100
1786
  ROWS 1000
1787
$$;
1788
	
1789
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1790
END;
1791
$_$;
1792

    
1793

    
1794
--
1795
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1796
--
1797

    
1798
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1799
    LANGUAGE plpgsql STRICT
1800
    AS $_$
1801
DECLARE
1802
	view_qual_name text = util.qual_name(view_);
1803
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1804
BEGIN
1805
	EXECUTE $$
1806
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1807
  RETURNS integer AS
1808
$BODY1$
1809
SELECT $$||quote_ident(row_num_col)||$$
1810
FROM $$||view_qual_name||$$
1811
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1812
LIMIT 1
1813
$BODY1$
1814
  LANGUAGE sql STABLE
1815
  COST 100;
1816
$$;
1817
	
1818
	EXECUTE $$
1819
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1820
  RETURNS SETOF $$||view_||$$ AS
1821
$BODY1$
1822
SELECT * FROM $$||view_qual_name||$$
1823
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1824
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1825
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1826
ORDER BY $$||quote_ident(row_num_col)||$$
1827
$BODY1$
1828
  LANGUAGE sql STABLE
1829
  COST 100
1830
  ROWS 1000
1831
$$;
1832
	
1833
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1834
END;
1835
$_$;
1836

    
1837

    
1838
--
1839
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1840
--
1841

    
1842
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1843
    LANGUAGE plpgsql STRICT
1844
    AS $_$
1845
DECLARE
1846
	view_qual_name text = util.qual_name(view_);
1847
BEGIN
1848
	EXECUTE $$
1849
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1850
  RETURNS SETOF $$||view_||$$
1851
  SET enable_sort TO 'off'
1852
  AS
1853
$BODY1$
1854
SELECT * FROM $$||view_qual_name||$$($2, $3)
1855
$BODY1$
1856
  LANGUAGE sql STABLE
1857
  COST 100
1858
  ROWS 1000
1859
;
1860
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1861
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1862
If you want to run EXPLAIN and get expanded output, use the regular subset
1863
function instead. (When a config param is set on a function, EXPLAIN produces
1864
just a function scan.)
1865
';
1866
$$;
1867
END;
1868
$_$;
1869

    
1870

    
1871
--
1872
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1873
--
1874

    
1875
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
1876
creates subset function which turns off enable_sort
1877
';
1878

    
1879

    
1880
--
1881
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
1882
--
1883

    
1884
CREATE FUNCTION name(table_ regclass) RETURNS text
1885
    LANGUAGE sql STABLE
1886
    AS $_$
1887
SELECT relname::text FROM pg_class WHERE oid = $1
1888
$_$;
1889

    
1890

    
1891
--
1892
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1893
--
1894

    
1895
CREATE FUNCTION name(type regtype) RETURNS text
1896
    LANGUAGE sql STABLE STRICT
1897
    AS $_$
1898
SELECT typname::text FROM pg_type WHERE oid = $1
1899
$_$;
1900

    
1901

    
1902
--
1903
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1904
--
1905

    
1906
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1907
    LANGUAGE sql IMMUTABLE
1908
    AS $_$
1909
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1910
$_$;
1911

    
1912

    
1913
--
1914
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1915
--
1916

    
1917
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1918
    LANGUAGE sql IMMUTABLE
1919
    AS $_$
1920
SELECT $1 IS NOT NULL
1921
$_$;
1922

    
1923

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

    
1928
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1929
    LANGUAGE sql IMMUTABLE
1930
    AS $_$
1931
SELECT util.hstore($1, NULL) || '*=>*'
1932
$_$;
1933

    
1934

    
1935
--
1936
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1937
--
1938

    
1939
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
1940
for use with _map()
1941
';
1942

    
1943

    
1944
--
1945
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1946
--
1947

    
1948
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1949
    LANGUAGE sql IMMUTABLE
1950
    AS $_$
1951
SELECT $2 + COALESCE($1, 0)
1952
$_$;
1953

    
1954

    
1955
--
1956
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
1957
--
1958

    
1959
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
1960
    LANGUAGE sql IMMUTABLE
1961
    AS $_$
1962
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
1963
$_$;
1964

    
1965

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

    
1970
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1971
    LANGUAGE sql STABLE
1972
    AS $_$
1973
SELECT util.type_qual_name($1::text::regtype)
1974
$_$;
1975

    
1976

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

    
1981
CREATE FUNCTION raise_notice(msg text) RETURNS void
1982
    LANGUAGE plpgsql IMMUTABLE STRICT
1983
    AS $$
1984
BEGIN
1985
	RAISE NOTICE '%', msg;
1986
END;
1987
$$;
1988

    
1989

    
1990
--
1991
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1992
--
1993

    
1994
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1995
    LANGUAGE plpgsql IMMUTABLE STRICT
1996
    AS $$
1997
BEGIN
1998
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1999
END;
2000
$$;
2001

    
2002

    
2003
--
2004
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2005
--
2006

    
2007
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2008
    LANGUAGE sql IMMUTABLE
2009
    AS $_$
2010
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2011
$_$;
2012

    
2013

    
2014
--
2015
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2016
--
2017

    
2018
CREATE FUNCTION rematerialize_view(table_ text, view_ regclass) RETURNS void
2019
    LANGUAGE sql
2020
    AS $_$
2021
SELECT util.drop_table($1);
2022
SELECT util.materialize_view($1, $2);
2023
$_$;
2024

    
2025

    
2026
--
2027
-- Name: FUNCTION rematerialize_view(table_ text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2028
--
2029

    
2030
COMMENT ON FUNCTION rematerialize_view(table_ text, view_ regclass) IS '
2031
idempotent, but repeats action each time
2032
';
2033

    
2034

    
2035
--
2036
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2037
--
2038

    
2039
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2040
    LANGUAGE sql STRICT
2041
    AS $_$
2042
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2043
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2044
FROM util.col_names($1::text::regtype) f (name);
2045
SELECT NULL::void; -- don't fold away functions called in previous query
2046
$_$;
2047

    
2048

    
2049
--
2050
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2051
--
2052

    
2053
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2054
idempotent
2055
';
2056

    
2057

    
2058
--
2059
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2060
--
2061

    
2062
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2063
    LANGUAGE sql STRICT
2064
    AS $_$
2065
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2066
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2067
SELECT util.set_col_names($1, $2);
2068
$_$;
2069

    
2070

    
2071
--
2072
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2073
--
2074

    
2075
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2076
idempotent.
2077
alters the names table, so it will need to be repopulated after running this function.
2078
';
2079

    
2080

    
2081
--
2082
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2083
--
2084

    
2085
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2086
    LANGUAGE sql STRICT
2087
    AS $_$
2088
SELECT util.drop_table($1);
2089
SELECT util.mk_map_table($1);
2090
$_$;
2091

    
2092

    
2093
--
2094
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2095
--
2096

    
2097
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2098
    LANGUAGE plpgsql STRICT
2099
    AS $_$
2100
DECLARE
2101
	result text = NULL;
2102
BEGIN
2103
	BEGIN
2104
		result = util.show_create_view(view_);
2105
		PERFORM util.eval($$DROP VIEW $$||view_);
2106
	EXCEPTION
2107
		WHEN undefined_table THEN NULL;
2108
	END;
2109
	RETURN result;
2110
END;
2111
$_$;
2112

    
2113

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

    
2118
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
2119
    LANGUAGE sql
2120
    AS $_$
2121
SELECT concat(util.save_drop_view(unnest)) FROM unnest($1)
2122
$_$;
2123

    
2124

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

    
2129
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
2130
    LANGUAGE sql STABLE
2131
    AS $_$
2132
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
2133
$_$;
2134

    
2135

    
2136
--
2137
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2138
--
2139

    
2140
CREATE FUNCTION schema(table_ regclass) RETURNS text
2141
    LANGUAGE sql STABLE
2142
    AS $_$
2143
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
2144
$_$;
2145

    
2146

    
2147
--
2148
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
2149
--
2150

    
2151
CREATE FUNCTION schema(type regtype) RETURNS text
2152
    LANGUAGE sql STABLE
2153
    AS $_$
2154
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
2155
$_$;
2156

    
2157

    
2158
--
2159
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
2160
--
2161

    
2162
CREATE FUNCTION schema(type_null anyelement) RETURNS text
2163
    LANGUAGE sql STABLE
2164
    AS $_$
2165
SELECT util.schema(pg_typeof($1))
2166
$_$;
2167

    
2168

    
2169
--
2170
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
2171
--
2172

    
2173
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
2174
    LANGUAGE sql STABLE
2175
    AS $_$
2176
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
2177
$_$;
2178

    
2179

    
2180
--
2181
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
2182
--
2183

    
2184
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
2185
a schema bundle is a group of schemas with a common prefix
2186
';
2187

    
2188

    
2189
--
2190
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2191
--
2192

    
2193
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
2194
    LANGUAGE sql
2195
    AS $_$
2196
SELECT util.schema_rename(old_schema,
2197
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
2198
FROM util.schema_bundle_get_schemas($1) f (old_schema);
2199
SELECT NULL::void; -- don't fold away functions called in previous query
2200
$_$;
2201

    
2202

    
2203
--
2204
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2205
--
2206

    
2207
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
2208
    LANGUAGE plpgsql
2209
    AS $$
2210
BEGIN
2211
	-- don't schema_bundle_rm() the schema_bundle to keep!
2212
	IF replace = with_ THEN RETURN; END IF;
2213
	
2214
	PERFORM util.schema_bundle_rm(replace);
2215
	PERFORM util.schema_bundle_rename(with_, replace);
2216
END;
2217
$$;
2218

    
2219

    
2220
--
2221
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
2222
--
2223

    
2224
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
2225
    LANGUAGE sql
2226
    AS $_$
2227
SELECT util.schema_rm(schema)
2228
FROM util.schema_bundle_get_schemas($1) f (schema);
2229
SELECT NULL::void; -- don't fold away functions called in previous query
2230
$_$;
2231

    
2232

    
2233
--
2234
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
2235
--
2236

    
2237
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
2238
    LANGUAGE sql STABLE
2239
    AS $_$
2240
SELECT quote_ident(util.schema($1))
2241
$_$;
2242

    
2243

    
2244
--
2245
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
2246
--
2247

    
2248
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2249
    LANGUAGE sql
2250
    AS $_$
2251
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2252
$_$;
2253

    
2254

    
2255
--
2256
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2257
--
2258

    
2259
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2260
    LANGUAGE plpgsql
2261
    AS $$
2262
BEGIN
2263
	-- don't schema_rm() the schema to keep!
2264
	IF replace = with_ THEN RETURN; END IF;
2265
	
2266
	PERFORM util.schema_rm(replace);
2267
	PERFORM util.schema_rename(with_, replace);
2268
END;
2269
$$;
2270

    
2271

    
2272
--
2273
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2274
--
2275

    
2276
CREATE FUNCTION schema_rm(schema text) RETURNS void
2277
    LANGUAGE sql
2278
    AS $_$
2279
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2280
$_$;
2281

    
2282

    
2283
--
2284
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2285
--
2286

    
2287
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2288
    LANGUAGE sql STRICT
2289
    AS $_$
2290
SELECT util.eval(
2291
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2292
$_$;
2293

    
2294

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

    
2299
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2300
    LANGUAGE plpgsql STRICT
2301
    AS $_$
2302
DECLARE
2303
    old text[] = ARRAY(SELECT util.col_names(table_));
2304
    new text[] = ARRAY(SELECT util.map_values(names));
2305
BEGIN
2306
    old = old[1:array_length(new, 1)]; -- truncate to same length
2307
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2308
||$$ TO $$||quote_ident(value))
2309
    FROM each(hstore(old, new))
2310
    WHERE value != key -- not same name
2311
    ;
2312
END;
2313
$_$;
2314

    
2315

    
2316
--
2317
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2318
--
2319

    
2320
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
2321
idempotent
2322
';
2323

    
2324

    
2325
--
2326
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2327
--
2328

    
2329
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2330
    LANGUAGE plpgsql STRICT
2331
    AS $_$
2332
DECLARE
2333
	row_ util.map;
2334
BEGIN
2335
	-- rename any metadata cols rather than re-adding them with new names
2336
	BEGIN
2337
		PERFORM util.set_col_names(table_, names);
2338
	EXCEPTION
2339
		WHEN array_subscript_error THEN -- selective suppress
2340
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2341
				-- metadata cols not yet added
2342
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2343
			END IF;
2344
	END;
2345
	
2346
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2347
	LOOP
2348
		PERFORM util.mk_const_col((table_, row_."to"),
2349
			substring(row_."from" from 2));
2350
	END LOOP;
2351
	
2352
	PERFORM util.set_col_names(table_, names);
2353
END;
2354
$_$;
2355

    
2356

    
2357
--
2358
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2359
--
2360

    
2361
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
2362
idempotent.
2363
the metadata mappings must be *last* in the names table.
2364
';
2365

    
2366

    
2367
--
2368
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2369
--
2370

    
2371
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2372
    LANGUAGE plpgsql STRICT
2373
    AS $_$
2374
DECLARE
2375
    sql text = $$ALTER TABLE $$||table_||$$
2376
$$||NULLIF(array_to_string(ARRAY(
2377
    SELECT
2378
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2379
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2380
    FROM
2381
    (
2382
        SELECT
2383
          quote_ident(col_name) AS col_name_sql
2384
        , util.col_type((table_, col_name)) AS curr_type
2385
        , type AS target_type
2386
        FROM unnest(col_casts)
2387
    ) s
2388
    WHERE curr_type != target_type
2389
), '
2390
, '), '');
2391
BEGIN
2392
    PERFORM util.debug_print_sql(sql);
2393
    EXECUTE COALESCE(sql, '');
2394
END;
2395
$_$;
2396

    
2397

    
2398
--
2399
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2400
--
2401

    
2402
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
2403
idempotent
2404
';
2405

    
2406

    
2407
--
2408
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2409
--
2410

    
2411
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2412
    LANGUAGE sql STABLE
2413
    AS $_$
2414
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2415
$$||util.show_grants_for($1)
2416
$_$;
2417

    
2418

    
2419
--
2420
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2421
--
2422

    
2423
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2424
    LANGUAGE sql STABLE
2425
    AS $_$
2426
SELECT concat(cmd)
2427
FROM
2428
(
2429
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2430
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2431
$$ ELSE '' END) AS cmd
2432
	FROM util.grants_users() f (user_)
2433
) s
2434
$_$;
2435

    
2436

    
2437
--
2438
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2439
--
2440

    
2441
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2442
    LANGUAGE plpgsql STABLE STRICT
2443
    AS $_$
2444
DECLARE
2445
    hstore hstore;
2446
BEGIN
2447
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2448
        table_||$$))$$ INTO STRICT hstore;
2449
    RETURN hstore;
2450
END;
2451
$_$;
2452

    
2453

    
2454
--
2455
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2456
--
2457

    
2458
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2459
    LANGUAGE sql STABLE STRICT
2460
    AS $_$
2461
SELECT COUNT(*) > 0 FROM pg_constraint
2462
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2463
$_$;
2464

    
2465

    
2466
--
2467
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2468
--
2469

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

    
2474

    
2475
--
2476
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2477
--
2478

    
2479
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2480
    LANGUAGE sql STRICT
2481
    AS $_$
2482
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2483
||quote_ident($2)||$$ CHECK (true)$$)
2484
$_$;
2485

    
2486

    
2487
--
2488
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2489
--
2490

    
2491
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
2492
stores a status flag by the presence of a table constraint.
2493
idempotent.
2494
';
2495

    
2496

    
2497
--
2498
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2499
--
2500

    
2501
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2502
    LANGUAGE sql STABLE STRICT
2503
    AS $_$
2504
SELECT util.table_flag__get($1, 'nulls_mapped')
2505
$_$;
2506

    
2507

    
2508
--
2509
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2510
--
2511

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

    
2516

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

    
2521
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2522
    LANGUAGE sql STRICT
2523
    AS $_$
2524
SELECT util.table_flag__set($1, 'nulls_mapped')
2525
$_$;
2526

    
2527

    
2528
--
2529
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2530
--
2531

    
2532
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
2533
sets that a table''s NULL-equivalent strings have been replaced with NULL.
2534
idempotent.
2535
';
2536

    
2537

    
2538
--
2539
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2540
--
2541

    
2542
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2543
    LANGUAGE plpgsql STRICT
2544
    AS $_$
2545
DECLARE
2546
    row record;
2547
BEGIN
2548
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2549
    LOOP
2550
        IF row.global_name != row.name THEN
2551
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2552
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2553
        END IF;
2554
    END LOOP;
2555
END;
2556
$_$;
2557

    
2558

    
2559
--
2560
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2561
--
2562

    
2563
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
2564
idempotent
2565
';
2566

    
2567

    
2568
--
2569
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2570
--
2571

    
2572
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2573
    LANGUAGE sql STRICT
2574
    AS $_$
2575
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2576
SELECT NULL::void; -- don't fold away functions called in previous query
2577
$_$;
2578

    
2579

    
2580
--
2581
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2582
--
2583

    
2584
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
2585
trims table_ to include only columns in the original data.
2586
idempotent.
2587
';
2588

    
2589

    
2590
--
2591
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2592
--
2593

    
2594
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2595
    LANGUAGE plpgsql STRICT
2596
    AS $_$
2597
BEGIN
2598
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2599
END;
2600
$_$;
2601

    
2602

    
2603
--
2604
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2605
--
2606

    
2607
COMMENT ON FUNCTION truncate(table_ regclass) IS '
2608
idempotent
2609
';
2610

    
2611

    
2612
--
2613
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
2614
--
2615

    
2616
CREATE FUNCTION try_create(sql text) RETURNS void
2617
    LANGUAGE plpgsql STRICT
2618
    AS $$
2619
BEGIN
2620
    PERFORM util.eval(sql);
2621
EXCEPTION
2622
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2623
    WHEN undefined_column THEN NULL;
2624
    WHEN duplicate_column THEN NULL;
2625
END;
2626
$$;
2627

    
2628

    
2629
--
2630
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2631
--
2632

    
2633
COMMENT ON FUNCTION try_create(sql text) IS '
2634
idempotent
2635
';
2636

    
2637

    
2638
--
2639
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2640
--
2641

    
2642
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2643
    LANGUAGE sql STRICT
2644
    AS $_$
2645
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2646
$_$;
2647

    
2648

    
2649
--
2650
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2651
--
2652

    
2653
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
2654
idempotent
2655
';
2656

    
2657

    
2658
--
2659
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2660
--
2661

    
2662
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2663
    LANGUAGE sql IMMUTABLE
2664
    AS $_$
2665
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2666
$_$;
2667

    
2668

    
2669
--
2670
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2671
--
2672

    
2673
COMMENT ON FUNCTION type_qual(value anyelement) IS '
2674
a type''s NOT NULL qualifier
2675
';
2676

    
2677

    
2678
--
2679
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2680
--
2681

    
2682
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
2683
    LANGUAGE sql STABLE STRICT
2684
    SET search_path TO pg_temp
2685
    AS $_$
2686
SELECT $1::text
2687
$_$;
2688

    
2689

    
2690
--
2691
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2692
--
2693

    
2694
COMMENT ON FUNCTION type_qual_name(type regtype) IS '
2695
a type''s schema-qualified name
2696
';
2697

    
2698

    
2699
--
2700
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
2701
--
2702

    
2703
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2704
    LANGUAGE plpgsql STABLE
2705
    AS $_$
2706
DECLARE
2707
    type regtype;
2708
BEGIN
2709
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2710
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2711
    RETURN type;
2712
END;
2713
$_$;
2714

    
2715

    
2716
--
2717
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2718
--
2719

    
2720
CREATE AGGREGATE all_same(anyelement) (
2721
    SFUNC = all_same_transform,
2722
    STYPE = anyarray,
2723
    FINALFUNC = all_same_final
2724
);
2725

    
2726

    
2727
--
2728
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2729
--
2730

    
2731
COMMENT ON AGGREGATE all_same(anyelement) IS '
2732
includes NULLs in comparison
2733
';
2734

    
2735

    
2736
--
2737
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2738
--
2739

    
2740
CREATE AGGREGATE join_strs(text, text) (
2741
    SFUNC = join_strs_transform,
2742
    STYPE = text
2743
);
2744

    
2745

    
2746
--
2747
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2748
--
2749

    
2750
CREATE OPERATOR -> (
2751
    PROCEDURE = map_get,
2752
    LEFTARG = regclass,
2753
    RIGHTARG = text
2754
);
2755

    
2756

    
2757
--
2758
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2759
--
2760

    
2761
CREATE OPERATOR => (
2762
    PROCEDURE = hstore,
2763
    LEFTARG = text[],
2764
    RIGHTARG = text
2765
);
2766

    
2767

    
2768
--
2769
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2770
--
2771

    
2772
COMMENT ON OPERATOR => (text[], text) IS '
2773
usage: array[''key1'', ...]::text[] => ''value''
2774
';
2775

    
2776

    
2777
--
2778
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2779
--
2780

    
2781
CREATE OPERATOR ?*>= (
2782
    PROCEDURE = is_populated_more_often_than,
2783
    LEFTARG = anyelement,
2784
    RIGHTARG = anyelement
2785
);
2786

    
2787

    
2788
--
2789
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2790
--
2791

    
2792
CREATE OPERATOR ?>= (
2793
    PROCEDURE = is_more_complete_than,
2794
    LEFTARG = anyelement,
2795
    RIGHTARG = anyelement
2796
);
2797

    
2798

    
2799
--
2800
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2801
--
2802

    
2803
CREATE OPERATOR ||% (
2804
    PROCEDURE = concat_esc,
2805
    LEFTARG = text,
2806
    RIGHTARG = text
2807
);
2808

    
2809

    
2810
--
2811
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2812
--
2813

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

    
2818

    
2819
--
2820
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2821
--
2822

    
2823
CREATE TABLE map (
2824
    "from" text NOT NULL,
2825
    "to" text,
2826
    filter text,
2827
    notes text
2828
);
2829

    
2830

    
2831
--
2832
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2833
--
2834

    
2835

    
2836

    
2837
--
2838
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2839
--
2840

    
2841

    
2842

    
2843
--
2844
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2845
--
2846

    
2847
ALTER TABLE ONLY map
2848
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2849

    
2850

    
2851
--
2852
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2853
--
2854

    
2855
ALTER TABLE ONLY map
2856
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2857

    
2858

    
2859
--
2860
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2861
--
2862

    
2863
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2864

    
2865

    
2866
--
2867
-- PostgreSQL database dump complete
2868
--
2869

    
(19-19/29)