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: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1008
--
1009

    
1010
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1011
    LANGUAGE sql IMMUTABLE
1012
    AS $_$
1013
SELECT util.array_fill($1, 0)
1014
$_$;
1015

    
1016

    
1017
--
1018
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1019
--
1020

    
1021
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)';
1022

    
1023

    
1024
--
1025
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1026
--
1027

    
1028
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1029
    LANGUAGE sql IMMUTABLE
1030
    AS $_$
1031
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1032
$_$;
1033

    
1034

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

    
1039
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1040
    LANGUAGE sql IMMUTABLE
1041
    AS $_$
1042
SELECT regexp_replace($2, '("?)$', $1||'\1')
1043
$_$;
1044

    
1045

    
1046
--
1047
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
1048
--
1049

    
1050
CREATE FUNCTION eval(sql text) RETURNS void
1051
    LANGUAGE plpgsql STRICT
1052
    AS $$
1053
BEGIN
1054
    RAISE NOTICE '%', sql;
1055
    EXECUTE sql;
1056
END;
1057
$$;
1058

    
1059

    
1060
--
1061
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1062
--
1063

    
1064
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1065
    LANGUAGE plpgsql
1066
    AS $$
1067
BEGIN
1068
	RAISE NOTICE '%', sql;
1069
	RETURN QUERY EXECUTE sql;
1070
END;
1071
$$;
1072

    
1073

    
1074
--
1075
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1076
--
1077

    
1078
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';
1079

    
1080

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

    
1085
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS SETOF anyelement
1086
    LANGUAGE plpgsql
1087
    AS $$
1088
BEGIN
1089
	RAISE NOTICE '%', sql;
1090
	RETURN QUERY EXECUTE sql;
1091
END;
1092
$$;
1093

    
1094

    
1095
--
1096
-- Name: FUNCTION eval2set(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1097
--
1098

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

    
1101

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

    
1106
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1107
    LANGUAGE plpgsql
1108
    AS $$
1109
DECLARE
1110
	ret_val ret_type_null%TYPE;
1111
BEGIN
1112
	RAISE NOTICE '%', sql;
1113
	EXECUTE sql INTO STRICT ret_val;
1114
	RETURN ret_val;
1115
END;
1116
$$;
1117

    
1118

    
1119
--
1120
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1121
--
1122

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

    
1125

    
1126
--
1127
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1128
--
1129

    
1130
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1131
    LANGUAGE sql
1132
    AS $_$
1133
SELECT util.eval2val($$SELECT $$||$1, $2)
1134
$_$;
1135

    
1136

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

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

    
1143

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

    
1148
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1149
    LANGUAGE sql
1150
    AS $_$
1151
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1152
$_$;
1153

    
1154

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

    
1159
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
1160
ret_type_null: NULL::ret_type';
1161

    
1162

    
1163
--
1164
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1165
--
1166

    
1167
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1168
    LANGUAGE sql STABLE STRICT
1169
    AS $_$
1170
SELECT col_name
1171
FROM unnest($2) s (col_name)
1172
WHERE util.col_exists(($1, col_name))
1173
$_$;
1174

    
1175

    
1176
--
1177
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1178
--
1179

    
1180
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1181
    LANGUAGE sql
1182
    AS $_$
1183
SELECT util.eval2set($$EXPLAIN $$||$1)
1184
$_$;
1185

    
1186

    
1187
--
1188
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1189
--
1190

    
1191
CREATE FUNCTION explain2notice(sql text) RETURNS void
1192
    LANGUAGE plpgsql
1193
    AS $_$
1194
BEGIN
1195
	RAISE NOTICE '%', $$EXPLAIN:
1196
$$||util.explain2str(sql);
1197
END;
1198
$_$;
1199

    
1200

    
1201
--
1202
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1203
--
1204

    
1205
CREATE FUNCTION explain2str(sql text) RETURNS text
1206
    LANGUAGE sql
1207
    AS $_$
1208
SELECT util.join_strs(explain, $$
1209
$$) FROM util.explain($1)
1210
$_$;
1211

    
1212

    
1213
SET default_tablespace = '';
1214

    
1215
SET default_with_oids = false;
1216

    
1217
--
1218
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1219
--
1220

    
1221
CREATE TABLE explain (
1222
    line text NOT NULL
1223
);
1224

    
1225

    
1226
--
1227
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1228
--
1229

    
1230
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1231
    LANGUAGE sql
1232
    AS $_$
1233
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1234
$$||quote_nullable($1)||$$
1235
)$$)
1236
$_$;
1237

    
1238

    
1239
--
1240
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1241
--
1242

    
1243
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS 'usage:
1244
PERFORM util.explain2table($$
1245
query
1246
$$);';
1247

    
1248

    
1249
--
1250
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1251
--
1252

    
1253
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1254
    LANGUAGE sql IMMUTABLE
1255
    AS $_$
1256
-- STRICT handles NULLs, so that the array will always be a value
1257
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1258
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1259
) END
1260
$_$;
1261

    
1262

    
1263
--
1264
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1265
--
1266

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

    
1269

    
1270
--
1271
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1272
--
1273

    
1274
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1275
    LANGUAGE plpgsql
1276
    AS $_$
1277
DECLARE
1278
	PG_EXCEPTION_DETAIL text;
1279
	recreate_users_cmd text = util.save_drop_views(users);
1280
BEGIN
1281
	PERFORM util.eval(cmd);
1282
	PERFORM util.eval(recreate_users_cmd);
1283
EXCEPTION
1284
WHEN dependent_objects_still_exist THEN
1285
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1286
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1287
	users = array(SELECT * FROM util.regexp_matches_group(
1288
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1289
	IF util.is_empty(users) THEN RAISE; END IF;
1290
	PERFORM util.force_recreate(cmd, users);
1291
END;
1292
$_$;
1293

    
1294

    
1295
--
1296
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1297
--
1298

    
1299
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS 'idempotent
1300

    
1301
users: not necessary to provide this because it will be autopopulated';
1302

    
1303

    
1304
--
1305
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1306
--
1307

    
1308
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1309
    LANGUAGE plpgsql STRICT
1310
    AS $_$
1311
DECLARE
1312
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1313
$$||query;
1314
BEGIN
1315
	EXECUTE mk_view;
1316
EXCEPTION
1317
WHEN invalid_table_definition THEN
1318
	IF SQLERRM = 'cannot drop columns from view'
1319
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1320
	THEN
1321
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1322
		EXECUTE mk_view;
1323
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1324
	END IF;
1325
END;
1326
$_$;
1327

    
1328

    
1329
--
1330
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1331
--
1332

    
1333
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
1334

    
1335

    
1336
--
1337
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1338
--
1339

    
1340
CREATE FUNCTION grants_users() RETURNS SETOF text
1341
    LANGUAGE sql IMMUTABLE
1342
    AS $$
1343
VALUES ('bien_read'), ('public_')
1344
$$;
1345

    
1346

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

    
1351
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1352
    LANGUAGE sql IMMUTABLE
1353
    AS $_$
1354
SELECT substring($2 for length($1)) = $1
1355
$_$;
1356

    
1357

    
1358
--
1359
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1360
--
1361

    
1362
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1363
    LANGUAGE sql IMMUTABLE
1364
    AS $_$
1365
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1366
$_$;
1367

    
1368

    
1369
--
1370
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1371
--
1372

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

    
1375

    
1376
--
1377
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1378
--
1379

    
1380
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1381
    LANGUAGE sql STABLE STRICT
1382
    AS $_$
1383
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1384
$_$;
1385

    
1386

    
1387
--
1388
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1389
--
1390

    
1391
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1392
    LANGUAGE sql IMMUTABLE
1393
    AS $_$
1394
SELECT util.array_length($1) = 0
1395
$_$;
1396

    
1397

    
1398
--
1399
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1400
--
1401

    
1402
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1403
    LANGUAGE sql IMMUTABLE
1404
    AS $_$
1405
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1406
$_$;
1407

    
1408

    
1409
--
1410
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1411
--
1412

    
1413
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1414
    LANGUAGE sql IMMUTABLE
1415
    AS $_$
1416
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1417
$_$;
1418

    
1419

    
1420
--
1421
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1422
--
1423

    
1424
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1425
    LANGUAGE sql IMMUTABLE STRICT
1426
    AS $_$
1427
SELECT $1 || $3 || $2
1428
$_$;
1429

    
1430

    
1431
--
1432
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1433
--
1434

    
1435
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1436
    LANGUAGE sql IMMUTABLE
1437
    AS $_$
1438
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1439
$_$;
1440

    
1441

    
1442
--
1443
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1444
--
1445

    
1446
CREATE FUNCTION map_filter_insert() RETURNS trigger
1447
    LANGUAGE plpgsql
1448
    AS $$
1449
BEGIN
1450
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1451
	RETURN new;
1452
END;
1453
$$;
1454

    
1455

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

    
1460
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1461
    LANGUAGE plpgsql STABLE STRICT
1462
    AS $_$
1463
DECLARE
1464
    value text;
1465
BEGIN
1466
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1467
        INTO value USING key;
1468
    RETURN value;
1469
END;
1470
$_$;
1471

    
1472

    
1473
--
1474
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1475
--
1476

    
1477
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1478
    LANGUAGE sql IMMUTABLE
1479
    AS $_$
1480
SELECT util._map(util.nulls_map($1), $2)
1481
$_$;
1482

    
1483

    
1484
--
1485
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1486
--
1487

    
1488
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].
1489

    
1490
[1] inlining of function calls, which is different from constant folding
1491
[2] _map()''s profiling query
1492
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1493
and map_nulls()''s profiling query
1494
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1495
both take ~920 ms.
1496
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.';
1497

    
1498

    
1499
--
1500
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1501
--
1502

    
1503
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1504
    LANGUAGE plpgsql STABLE STRICT
1505
    AS $_$
1506
BEGIN
1507
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1508
END;
1509
$_$;
1510

    
1511

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

    
1516
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1517
    LANGUAGE sql STRICT
1518
    AS $_$
1519
SELECT util.create_if_not_exists($$
1520
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1521
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1522
||quote_literal($2)||$$;
1523
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1524
$$)
1525
$_$;
1526

    
1527

    
1528
--
1529
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1530
--
1531

    
1532
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1533

    
1534

    
1535
--
1536
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1537
--
1538

    
1539
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
1540
    LANGUAGE plpgsql STRICT
1541
    AS $_$
1542
DECLARE
1543
    type regtype = util.typeof(expr, col.table_::text::regtype);
1544
    col_name_sql text = quote_ident(col.name);
1545
BEGIN
1546
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
1547
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
1548
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1549
$$||expr||$$;
1550
$$);
1551
END;
1552
$_$;
1553

    
1554

    
1555
--
1556
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
1557
--
1558

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

    
1561

    
1562
--
1563
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1564
--
1565

    
1566
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1567
    LANGUAGE sql STRICT
1568
    AS $_$
1569
SELECT util.create_if_not_exists($$
1570
CREATE TABLE $$||$1||$$
1571
(
1572
    LIKE util.map INCLUDING ALL
1573
);
1574

    
1575
CREATE TRIGGER map_filter_insert
1576
  BEFORE INSERT
1577
  ON $$||$1||$$
1578
  FOR EACH ROW
1579
  EXECUTE PROCEDURE util.map_filter_insert();
1580
$$)
1581
$_$;
1582

    
1583

    
1584
--
1585
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1586
--
1587

    
1588
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1589
    LANGUAGE sql STRICT
1590
    AS $_$
1591
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1592
$_$;
1593

    
1594

    
1595
--
1596
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1597
--
1598

    
1599
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1600

    
1601

    
1602
--
1603
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1604
--
1605

    
1606
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
1607
    LANGUAGE plpgsql STRICT
1608
    AS $_$
1609
DECLARE
1610
	view_qual_name text = util.qual_name(view_);
1611
BEGIN
1612
	EXECUTE $$
1613
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1614
  RETURNS SETOF $$||view_||$$ AS
1615
$BODY1$
1616
SELECT * FROM $$||view_qual_name||$$
1617
ORDER BY sort_col
1618
LIMIT $1 OFFSET $2
1619
$BODY1$
1620
  LANGUAGE sql STABLE
1621
  COST 100
1622
  ROWS 1000
1623
$$;
1624
	
1625
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1626
END;
1627
$_$;
1628

    
1629

    
1630
--
1631
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1632
--
1633

    
1634
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1635
    LANGUAGE plpgsql STRICT
1636
    AS $_$
1637
DECLARE
1638
	view_qual_name text = util.qual_name(view_);
1639
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
1640
BEGIN
1641
	EXECUTE $$
1642
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
1643
  RETURNS integer AS
1644
$BODY1$
1645
SELECT $$||quote_ident(row_num_col)||$$
1646
FROM $$||view_qual_name||$$
1647
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
1648
LIMIT 1
1649
$BODY1$
1650
  LANGUAGE sql STABLE
1651
  COST 100;
1652
$$;
1653
	
1654
	EXECUTE $$
1655
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1656
  RETURNS SETOF $$||view_||$$ AS
1657
$BODY1$
1658
SELECT * FROM $$||view_qual_name||$$
1659
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
1660
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
1661
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
1662
ORDER BY $$||quote_ident(row_num_col)||$$
1663
$BODY1$
1664
  LANGUAGE sql STABLE
1665
  COST 100
1666
  ROWS 1000
1667
$$;
1668
	
1669
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
1670
END;
1671
$_$;
1672

    
1673

    
1674
--
1675
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
1676
--
1677

    
1678
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
1679
    LANGUAGE plpgsql STRICT
1680
    AS $_$
1681
DECLARE
1682
	view_qual_name text = util.qual_name(view_);
1683
BEGIN
1684
	EXECUTE $$
1685
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1686
  RETURNS SETOF $$||view_||$$
1687
  SET enable_sort TO 'off'
1688
  AS
1689
$BODY1$
1690
SELECT * FROM $$||view_qual_name||$$($2, $3)
1691
$BODY1$
1692
  LANGUAGE sql STABLE
1693
  COST 100
1694
  ROWS 1000
1695
;
1696
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1697
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1698
If you want to run EXPLAIN and get expanded output, use the regular subset
1699
function instead. (When a config param is set on a function, EXPLAIN produces
1700
just a function scan.)
1701
';
1702
$$;
1703
END;
1704
$_$;
1705

    
1706

    
1707
--
1708
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
1709
--
1710

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

    
1713

    
1714
--
1715
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1716
--
1717

    
1718
CREATE FUNCTION name(type regtype) RETURNS text
1719
    LANGUAGE sql STABLE STRICT
1720
    AS $_$
1721
SELECT typname::text FROM pg_type WHERE oid = $1
1722
$_$;
1723

    
1724

    
1725
--
1726
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1727
--
1728

    
1729
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1730
    LANGUAGE sql IMMUTABLE
1731
    AS $_$
1732
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
1733
$_$;
1734

    
1735

    
1736
--
1737
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1738
--
1739

    
1740
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1741
    LANGUAGE sql IMMUTABLE
1742
    AS $_$
1743
SELECT $1 IS NOT NULL
1744
$_$;
1745

    
1746

    
1747
--
1748
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
1749
--
1750

    
1751
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
1752
    LANGUAGE sql IMMUTABLE
1753
    AS $_$
1754
SELECT util.hstore($1, NULL) || '*=>*'
1755
$_$;
1756

    
1757

    
1758
--
1759
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
1760
--
1761

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

    
1764

    
1765
--
1766
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
1767
--
1768

    
1769
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
1770
    LANGUAGE sql IMMUTABLE
1771
    AS $_$
1772
SELECT $2 + COALESCE($1, 0)
1773
$_$;
1774

    
1775

    
1776
--
1777
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
1778
--
1779

    
1780
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
1781
    LANGUAGE sql STABLE
1782
    AS $_$
1783
SELECT util.type_qual_name($1::text::regtype)
1784
$_$;
1785

    
1786

    
1787
--
1788
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1789
--
1790

    
1791
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1792
    LANGUAGE plpgsql IMMUTABLE STRICT
1793
    AS $$
1794
BEGIN
1795
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1796
END;
1797
$$;
1798

    
1799

    
1800
--
1801
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
1802
--
1803

    
1804
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
1805
    LANGUAGE sql IMMUTABLE
1806
    AS $_$
1807
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
1808
$_$;
1809

    
1810

    
1811
--
1812
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1813
--
1814

    
1815
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1816
    LANGUAGE sql STRICT
1817
    AS $_$
1818
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1819
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1820
FROM util.col_names($1::text::regtype) f (name);
1821
SELECT NULL::void; -- don't fold away functions called in previous query
1822
$_$;
1823

    
1824

    
1825
--
1826
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1827
--
1828

    
1829
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1830

    
1831

    
1832
--
1833
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1834
--
1835

    
1836
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
1837
    LANGUAGE sql STRICT
1838
    AS $_$
1839
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
1840
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
1841
SELECT util.set_col_names($1, $2);
1842
$_$;
1843

    
1844

    
1845
--
1846
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1847
--
1848

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

    
1852

    
1853
--
1854
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856

    
1857
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1858
    LANGUAGE sql STRICT
1859
    AS $_$
1860
SELECT util.drop_table($1);
1861
SELECT util.mk_map_table($1);
1862
$_$;
1863

    
1864

    
1865
--
1866
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
1867
--
1868

    
1869
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
1870
    LANGUAGE plpgsql STRICT
1871
    AS $_$
1872
DECLARE
1873
	result text = NULL;
1874
BEGIN
1875
	BEGIN
1876
		result = util.show_create_view(view_);
1877
		PERFORM util.eval($$DROP VIEW $$||view_);
1878
	EXCEPTION
1879
		WHEN undefined_table THEN NULL;
1880
	END;
1881
	RETURN result;
1882
END;
1883
$_$;
1884

    
1885

    
1886
--
1887
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
1888
--
1889

    
1890
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
1891
    LANGUAGE sql
1892
    AS $_$
1893
SELECT concat(util.save_drop_view(unnest)) FROM unnest($1)
1894
$_$;
1895

    
1896

    
1897
--
1898
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
1899
--
1900

    
1901
CREATE FUNCTION schema(type regtype) RETURNS text
1902
    LANGUAGE sql STABLE
1903
    AS $_$
1904
SELECT nspname::text
1905
FROM pg_type
1906
JOIN pg_namespace ON pg_namespace.oid = typnamespace
1907
WHERE pg_type.oid = $1
1908
$_$;
1909

    
1910

    
1911
--
1912
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
1913
--
1914

    
1915
CREATE FUNCTION schema(type_null anyelement) RETURNS text
1916
    LANGUAGE sql STABLE
1917
    AS $_$
1918
SELECT util.schema(pg_typeof($1))
1919
$_$;
1920

    
1921

    
1922
--
1923
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
1924
--
1925

    
1926
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
1927
    LANGUAGE sql STABLE
1928
    AS $_$
1929
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
1930
$_$;
1931

    
1932

    
1933
--
1934
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
1935
--
1936

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

    
1939

    
1940
--
1941
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
1942
--
1943

    
1944
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
1945
    LANGUAGE sql
1946
    AS $_$
1947
SELECT util.schema_rename(old_schema,
1948
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
1949
FROM util.schema_bundle_get_schemas($1) f (old_schema);
1950
SELECT NULL::void; -- don't fold away functions called in previous query
1951
$_$;
1952

    
1953

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

    
1958
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
1959
    LANGUAGE plpgsql
1960
    AS $$
1961
BEGIN
1962
	-- don't schema_bundle_rm() the schema_bundle to keep!
1963
	IF replace = with_ THEN RETURN; END IF;
1964
	
1965
	PERFORM util.schema_bundle_rm(replace);
1966
	PERFORM util.schema_bundle_rename(with_, replace);
1967
END;
1968
$$;
1969

    
1970

    
1971
--
1972
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
1973
--
1974

    
1975
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
1976
    LANGUAGE sql
1977
    AS $_$
1978
SELECT util.schema_rm(schema)
1979
FROM util.schema_bundle_get_schemas($1) f (schema);
1980
SELECT NULL::void; -- don't fold away functions called in previous query
1981
$_$;
1982

    
1983

    
1984
--
1985
-- Name: schema_ident(anyelement); Type: FUNCTION; Schema: util; Owner: -
1986
--
1987

    
1988
CREATE FUNCTION schema_ident(type_null anyelement) RETURNS text
1989
    LANGUAGE sql STABLE
1990
    AS $_$
1991
SELECT quote_ident(util.schema($1))
1992
$_$;
1993

    
1994

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

    
1999
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
2000
    LANGUAGE sql
2001
    AS $_$
2002
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
2003
$_$;
2004

    
2005

    
2006
--
2007
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
2008
--
2009

    
2010
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
2011
    LANGUAGE plpgsql
2012
    AS $$
2013
BEGIN
2014
	-- don't schema_rm() the schema to keep!
2015
	IF replace = with_ THEN RETURN; END IF;
2016
	
2017
	PERFORM util.schema_rm(replace);
2018
	PERFORM util.schema_rename(with_, replace);
2019
END;
2020
$$;
2021

    
2022

    
2023
--
2024
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
2025
--
2026

    
2027
CREATE FUNCTION schema_rm(schema text) RETURNS void
2028
    LANGUAGE sql
2029
    AS $_$
2030
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
2031
$_$;
2032

    
2033

    
2034
--
2035
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
2036
--
2037

    
2038
CREATE FUNCTION search_path_append(schemas text) RETURNS void
2039
    LANGUAGE sql STRICT
2040
    AS $_$
2041
SELECT util.eval(
2042
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
2043
$_$;
2044

    
2045

    
2046
--
2047
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2048
--
2049

    
2050
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
2051
    LANGUAGE plpgsql STRICT
2052
    AS $_$
2053
DECLARE
2054
    old text[] = ARRAY(SELECT util.col_names(table_));
2055
    new text[] = ARRAY(SELECT util.map_values(names));
2056
BEGIN
2057
    old = old[1:array_length(new, 1)]; -- truncate to same length
2058
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
2059
||$$ TO $$||quote_ident(value))
2060
    FROM each(hstore(old, new))
2061
    WHERE value != key -- not same name
2062
    ;
2063
END;
2064
$_$;
2065

    
2066

    
2067
--
2068
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2069
--
2070

    
2071
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
2072

    
2073

    
2074
--
2075
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2076
--
2077

    
2078
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
2079
    LANGUAGE plpgsql STRICT
2080
    AS $_$
2081
DECLARE
2082
	row_ util.map;
2083
BEGIN
2084
	-- rename any metadata cols rather than re-adding them with new names
2085
	BEGIN
2086
		PERFORM util.set_col_names(table_, names);
2087
	EXCEPTION
2088
		WHEN array_subscript_error THEN -- selective suppress
2089
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
2090
				-- metadata cols not yet added
2091
			ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM; -- rethrow
2092
			END IF;
2093
	END;
2094
	
2095
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
2096
	LOOP
2097
		PERFORM util.mk_const_col((table_, row_."to"),
2098
			substring(row_."from" from 2));
2099
	END LOOP;
2100
	
2101
	PERFORM util.set_col_names(table_, names);
2102
END;
2103
$_$;
2104

    
2105

    
2106
--
2107
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2108
--
2109

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

    
2113

    
2114
--
2115
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2116
--
2117

    
2118
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
2119
    LANGUAGE plpgsql STRICT
2120
    AS $_$
2121
DECLARE
2122
    sql text = $$ALTER TABLE $$||table_||$$
2123
$$||NULLIF(array_to_string(ARRAY(
2124
    SELECT
2125
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
2126
    ||$$ USING $$||col_name_sql||$$::$$||target_type
2127
    FROM
2128
    (
2129
        SELECT
2130
          quote_ident(col_name) AS col_name_sql
2131
        , util.col_type((table_, col_name)) AS curr_type
2132
        , type AS target_type
2133
        FROM unnest(col_casts)
2134
    ) s
2135
    WHERE curr_type != target_type
2136
), '
2137
, '), '');
2138
BEGIN
2139
    RAISE NOTICE '%', sql;
2140
    EXECUTE COALESCE(sql, '');
2141
END;
2142
$_$;
2143

    
2144

    
2145
--
2146
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
2147
--
2148

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

    
2151

    
2152
--
2153
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2154
--
2155

    
2156
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
2157
    LANGUAGE sql STABLE
2158
    AS $_$
2159
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
2160
$$||util.show_grants_for($1)
2161
$_$;
2162

    
2163

    
2164
--
2165
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
2166
--
2167

    
2168
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
2169
    LANGUAGE sql STABLE
2170
    AS $_$
2171
SELECT concat(cmd)
2172
FROM
2173
(
2174
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
2175
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
2176
$$ ELSE '' END) AS cmd
2177
	FROM util.grants_users() f (user_)
2178
) s
2179
$_$;
2180

    
2181

    
2182
--
2183
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
2184
--
2185

    
2186
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
2187
    LANGUAGE plpgsql STABLE STRICT
2188
    AS $_$
2189
DECLARE
2190
    hstore hstore;
2191
BEGIN
2192
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
2193
        table_||$$))$$ INTO STRICT hstore;
2194
    RETURN hstore;
2195
END;
2196
$_$;
2197

    
2198

    
2199
--
2200
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2201
--
2202

    
2203
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
2204
    LANGUAGE sql STABLE STRICT
2205
    AS $_$
2206
SELECT COUNT(*) > 0 FROM pg_constraint
2207
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
2208
$_$;
2209

    
2210

    
2211
--
2212
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2213
--
2214

    
2215
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';
2216

    
2217

    
2218
--
2219
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2220
--
2221

    
2222
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
2223
    LANGUAGE sql STRICT
2224
    AS $_$
2225
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
2226
||quote_ident($2)||$$ CHECK (true)$$)
2227
$_$;
2228

    
2229

    
2230
--
2231
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
2232
--
2233

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

    
2237

    
2238
--
2239
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
2240
--
2241

    
2242
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
2243
    LANGUAGE sql STABLE STRICT
2244
    AS $_$
2245
SELECT util.table_flag__get($1, 'nulls_mapped')
2246
$_$;
2247

    
2248

    
2249
--
2250
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2251
--
2252

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

    
2255

    
2256
--
2257
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
2258
--
2259

    
2260
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
2261
    LANGUAGE sql STRICT
2262
    AS $_$
2263
SELECT util.table_flag__set($1, 'nulls_mapped')
2264
$_$;
2265

    
2266

    
2267
--
2268
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2269
--
2270

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

    
2274

    
2275
--
2276
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
2277
--
2278

    
2279
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
2280
    LANGUAGE sql STABLE STRICT
2281
    AS $_$
2282
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
2283
$_$;
2284

    
2285

    
2286
--
2287
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
2288
--
2289

    
2290
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
2291
    LANGUAGE plpgsql STRICT
2292
    AS $_$
2293
DECLARE
2294
    row record;
2295
BEGIN
2296
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
2297
    LOOP
2298
        IF row.global_name != row.name THEN
2299
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
2300
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
2301
        END IF;
2302
    END LOOP;
2303
END;
2304
$_$;
2305

    
2306

    
2307
--
2308
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2309
--
2310

    
2311
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
2312

    
2313

    
2314
--
2315
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2316
--
2317

    
2318
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
2319
    LANGUAGE sql STRICT
2320
    AS $_$
2321
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
2322
SELECT NULL::void; -- don't fold away functions called in previous query
2323
$_$;
2324

    
2325

    
2326
--
2327
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2328
--
2329

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

    
2333

    
2334
--
2335
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
2336
--
2337

    
2338
CREATE FUNCTION truncate(table_ regclass) RETURNS void
2339
    LANGUAGE plpgsql STRICT
2340
    AS $_$
2341
BEGIN
2342
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
2343
END;
2344
$_$;
2345

    
2346

    
2347
--
2348
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2349
--
2350

    
2351
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
2352

    
2353

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

    
2358
CREATE FUNCTION try_create(sql text) RETURNS void
2359
    LANGUAGE plpgsql STRICT
2360
    AS $$
2361
BEGIN
2362
    PERFORM util.eval(sql);
2363
EXCEPTION
2364
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
2365
    WHEN undefined_column THEN NULL;
2366
    WHEN duplicate_column THEN NULL;
2367
END;
2368
$$;
2369

    
2370

    
2371
--
2372
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
2373
--
2374

    
2375
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
2376

    
2377

    
2378
--
2379
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
2380
--
2381

    
2382
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
2383
    LANGUAGE sql STRICT
2384
    AS $_$
2385
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
2386
$_$;
2387

    
2388

    
2389
--
2390
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
2391
--
2392

    
2393
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
2394

    
2395

    
2396
--
2397
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
2398
--
2399

    
2400
CREATE FUNCTION type_qual(value anyelement) RETURNS text
2401
    LANGUAGE sql IMMUTABLE
2402
    AS $_$
2403
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
2404
$_$;
2405

    
2406

    
2407
--
2408
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
2409
--
2410

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

    
2413

    
2414
--
2415
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2416
--
2417

    
2418
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
2419
    LANGUAGE sql STABLE STRICT
2420
    SET search_path TO pg_temp
2421
    AS $_$
2422
SELECT $1::text
2423
$_$;
2424

    
2425

    
2426
--
2427
-- Name: FUNCTION type_qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2428
--
2429

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

    
2432

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

    
2437
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
2438
    LANGUAGE plpgsql STABLE
2439
    AS $_$
2440
DECLARE
2441
    type regtype;
2442
BEGIN
2443
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
2444
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
2445
    RETURN type;
2446
END;
2447
$_$;
2448

    
2449

    
2450
--
2451
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
2452
--
2453

    
2454
CREATE AGGREGATE all_same(anyelement) (
2455
    SFUNC = all_same_transform,
2456
    STYPE = anyarray,
2457
    FINALFUNC = all_same_final
2458
);
2459

    
2460

    
2461
--
2462
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
2463
--
2464

    
2465
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
2466

    
2467

    
2468
--
2469
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
2470
--
2471

    
2472
CREATE AGGREGATE join_strs(text, text) (
2473
    SFUNC = join_strs_transform,
2474
    STYPE = text
2475
);
2476

    
2477

    
2478
--
2479
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
2480
--
2481

    
2482
CREATE OPERATOR -> (
2483
    PROCEDURE = map_get,
2484
    LEFTARG = regclass,
2485
    RIGHTARG = text
2486
);
2487

    
2488

    
2489
--
2490
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
2491
--
2492

    
2493
CREATE OPERATOR => (
2494
    PROCEDURE = hstore,
2495
    LEFTARG = text[],
2496
    RIGHTARG = text
2497
);
2498

    
2499

    
2500
--
2501
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
2502
--
2503

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

    
2506

    
2507
--
2508
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
2509
--
2510

    
2511
CREATE OPERATOR ?*>= (
2512
    PROCEDURE = is_populated_more_often_than,
2513
    LEFTARG = anyelement,
2514
    RIGHTARG = anyelement
2515
);
2516

    
2517

    
2518
--
2519
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
2520
--
2521

    
2522
CREATE OPERATOR ?>= (
2523
    PROCEDURE = is_more_complete_than,
2524
    LEFTARG = anyelement,
2525
    RIGHTARG = anyelement
2526
);
2527

    
2528

    
2529
--
2530
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
2531
--
2532

    
2533
CREATE OPERATOR ||% (
2534
    PROCEDURE = concat_esc,
2535
    LEFTARG = text,
2536
    RIGHTARG = text
2537
);
2538

    
2539

    
2540
--
2541
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
2542
--
2543

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

    
2546

    
2547
--
2548
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
2549
--
2550

    
2551
CREATE TABLE map (
2552
    "from" text NOT NULL,
2553
    "to" text,
2554
    filter text,
2555
    notes text
2556
);
2557

    
2558

    
2559
--
2560
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
2561
--
2562

    
2563

    
2564

    
2565
--
2566
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
2567
--
2568

    
2569

    
2570

    
2571
--
2572
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2573
--
2574

    
2575
ALTER TABLE ONLY map
2576
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
2577

    
2578

    
2579
--
2580
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
2581
--
2582

    
2583
ALTER TABLE ONLY map
2584
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
2585

    
2586

    
2587
--
2588
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
2589
--
2590

    
2591
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
2592

    
2593

    
2594
--
2595
-- PostgreSQL database dump complete
2596
--
2597

    
(19-19/29)