Project

General

Profile

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

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

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

    
15
CREATE SCHEMA util;
16

    
17

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

    
22
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.';
23

    
24

    
25
SET search_path = util, pg_catalog;
26

    
27
--
28
-- Name: col_cast; Type: TYPE; Schema: util; Owner: -
29
--
30

    
31
CREATE TYPE col_cast AS (
32
	col_name text,
33
	type regtype
34
);
35

    
36

    
37
--
38
-- Name: col_ref; Type: TYPE; Schema: util; Owner: -
39
--
40

    
41
CREATE TYPE col_ref AS (
42
	table_ regclass,
43
	name text
44
);
45

    
46

    
47
--
48
-- Name: compass_dir; Type: TYPE; Schema: util; Owner: -
49
--
50

    
51
CREATE TYPE compass_dir AS ENUM (
52
    'N',
53
    'E',
54
    'S',
55
    'W'
56
);
57

    
58

    
59
--
60
-- Name: datatype; Type: TYPE; Schema: util; Owner: -
61
--
62

    
63
CREATE TYPE datatype AS ENUM (
64
    'str',
65
    'float'
66
);
67

    
68

    
69
--
70
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
71
--
72

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

    
79

    
80
--
81
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
82
--
83

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

    
99

    
100
--
101
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
102
--
103

    
104
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.';
105

    
106

    
107
--
108
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
109
--
110

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

    
126

    
127
--
128
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
129
--
130

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

    
145

    
146
--
147
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
148
--
149

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

    
163

    
164
--
165
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
166
--
167

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

    
174

    
175
--
176
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
177
--
178

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

    
185

    
186
--
187
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
188
--
189

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

    
198

    
199
--
200
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
201
--
202

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

    
209

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

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

    
220

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

    
225
CREATE FUNCTION _join("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
226
    LANGUAGE sql IMMUTABLE
227
    AS $_$
228
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
229
$_$;
230

    
231

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

    
236
CREATE FUNCTION _join_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
237
    LANGUAGE sql IMMUTABLE
238
    AS $_$
239
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
240
$_$;
241

    
242

    
243
--
244
-- Name: _label(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
245
--
246

    
247
CREATE FUNCTION _label(label anyelement, value anyelement) RETURNS anyelement
248
    LANGUAGE sql IMMUTABLE
249
    AS $_$
250
SELECT coalesce($1 || ': ', '') || $2
251
$_$;
252

    
253

    
254
--
255
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
256
--
257

    
258
CREATE FUNCTION _lowercase(value text) RETURNS text
259
    LANGUAGE sql IMMUTABLE STRICT
260
    AS $_$
261
SELECT lower($1)
262
$_$;
263

    
264

    
265
--
266
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
267
--
268

    
269
CREATE FUNCTION _map(map hstore, value text) RETURNS text
270
    LANGUAGE plpgsql IMMUTABLE STRICT
271
    AS $$
272
DECLARE
273
    match text := map -> value;
274
BEGIN
275
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
276
        match := map -> '*'; -- use default entry
277
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
278
        END IF;
279
    END IF;
280
    
281
    -- Interpret result
282
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
283
    ELSIF match = '*' THEN RETURN value;
284
    ELSE RETURN match;
285
    END IF;
286
END;
287
$$;
288

    
289

    
290
--
291
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
292
--
293

    
294
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
295
    LANGUAGE sql IMMUTABLE
296
    AS $_$
297
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
298
$_$;
299

    
300

    
301
--
302
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
303
--
304

    
305
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
306
    LANGUAGE sql IMMUTABLE
307
    AS $_$
308
SELECT util.join_strs(value, '; ')
309
FROM
310
(
311
    SELECT *
312
    FROM
313
    (
314
        SELECT
315
        DISTINCT ON (value)
316
        *
317
        FROM
318
        (VALUES
319
              (1, $1)
320
            , (2, $2)
321
            , (3, $3)
322
            , (4, $4)
323
            , (5, $5)
324
            , (6, $6)
325
            , (7, $7)
326
            , (8, $8)
327
            , (9, $9)
328
            , (10, $10)
329
        )
330
        AS v (sort_order, value)
331
        WHERE value IS NOT NULL
332
    )
333
    AS v
334
    ORDER BY sort_order
335
)
336
AS v
337
$_$;
338

    
339

    
340
--
341
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
342
--
343

    
344
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
345
    LANGUAGE sql IMMUTABLE
346
    AS $_$
347
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
348
$_$;
349

    
350

    
351
--
352
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
353
--
354

    
355
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
356
    LANGUAGE sql IMMUTABLE
357
    AS $_$
358
SELECT util.join_strs(value, ' ')
359
FROM
360
(
361
    SELECT *
362
    FROM
363
    (
364
        SELECT
365
        DISTINCT ON (value)
366
        *
367
        FROM
368
        (VALUES
369
              (1, $1)
370
            , (2, $2)
371
            , (3, $3)
372
            , (4, $4)
373
            , (5, $5)
374
            , (6, $6)
375
            , (7, $7)
376
            , (8, $8)
377
            , (9, $9)
378
            , (10, $10)
379
        )
380
        AS v (sort_order, value)
381
        WHERE value IS NOT NULL
382
    )
383
    AS v
384
    ORDER BY sort_order
385
)
386
AS v
387
$_$;
388

    
389

    
390
--
391
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
392
--
393

    
394
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
395
    LANGUAGE sql IMMUTABLE
396
    AS $_$
397
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
398
$_$;
399

    
400

    
401
--
402
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
403
--
404

    
405
CREATE FUNCTION _not(value boolean) RETURNS boolean
406
    LANGUAGE sql IMMUTABLE STRICT
407
    AS $_$
408
SELECT NOT $1
409
$_$;
410

    
411

    
412
--
413
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
414
--
415

    
416
CREATE FUNCTION _now() RETURNS timestamp with time zone
417
    LANGUAGE sql STABLE
418
    AS $$
419
SELECT now()
420
$$;
421

    
422

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

    
427
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
428
    LANGUAGE plpgsql IMMUTABLE
429
    AS $$
430
DECLARE
431
    type util.datatype NOT NULL := type; -- add NOT NULL
432
BEGIN
433
    IF type = 'str' THEN RETURN nullif(value::text, "null");
434
    -- Invalid value is ignored, but invalid null value generates error
435
    ELSIF type = 'float' THEN
436
        DECLARE
437
            -- Outside the try block so that invalid null value generates error
438
            "null" double precision := "null"::double precision;
439
        BEGIN
440
            RETURN nullif(value::double precision, "null");
441
        EXCEPTION
442
            WHEN data_exception THEN RETURN value; -- ignore invalid value
443
        END;
444
    END IF;
445
END;
446
$$;
447

    
448

    
449
--
450
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
451
--
452

    
453
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
454
    LANGUAGE sql IMMUTABLE
455
    AS $_$
456
SELECT util."_nullIf"($1, $2, $3::util.datatype)
457
$_$;
458

    
459

    
460
--
461
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
462
--
463

    
464
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
465
    LANGUAGE sql IMMUTABLE
466
    AS $_$
467
SELECT bool_or(value)
468
FROM
469
(VALUES
470
      ($1)
471
    , ($2)
472
    , ($3)
473
    , ($4)
474
    , ($5)
475
)
476
AS v (value)
477
$_$;
478

    
479

    
480
--
481
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
482
--
483

    
484
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.';
485

    
486

    
487
--
488
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
489
--
490

    
491
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
492
    LANGUAGE sql IMMUTABLE
493
    AS $_$
494
SELECT $2 - $1
495
$_$;
496

    
497

    
498
--
499
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
500
--
501

    
502
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
503
    LANGUAGE sql IMMUTABLE STRICT
504
    AS $_$
505
SELECT regexp_split_to_table($1, $2)
506
$_$;
507

    
508

    
509
--
510
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
511
--
512

    
513
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
514
    LANGUAGE sql IMMUTABLE
515
    AS $_$
516
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
517
$_$;
518

    
519

    
520
--
521
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
522
--
523

    
524
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
525
    LANGUAGE plpgsql IMMUTABLE
526
    AS $$
527
DECLARE
528
	value_cmp         state%TYPE = ARRAY[value];
529
	state             state%TYPE = COALESCE(state, value_cmp);
530
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
531
BEGIN
532
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
533
END;
534
$$;
535

    
536

    
537
--
538
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
539
--
540

    
541
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
542
    LANGUAGE sql STABLE STRICT
543
    AS $_$
544
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
545
$_$;
546

    
547

    
548
--
549
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
550
--
551

    
552
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
553
    LANGUAGE plpgsql STRICT
554
    AS $_$
555
BEGIN
556
    -- not yet clustered (ARRAY[] compares NULLs literally)
557
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
558
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
559
    END IF;
560
END;
561
$_$;
562

    
563

    
564
--
565
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
566
--
567

    
568
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS 'idempotent';
569

    
570

    
571
--
572
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
573
--
574

    
575
CREATE FUNCTION col_comment(col col_ref) RETURNS text
576
    LANGUAGE plpgsql STABLE STRICT
577
    AS $$
578
DECLARE
579
	comment text;
580
BEGIN
581
	SELECT description
582
	FROM pg_attribute
583
	LEFT JOIN pg_description ON objoid = attrelid
584
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
585
	WHERE attrelid = col.table_ AND attname = col.name
586
	INTO STRICT comment
587
	;
588
	RETURN comment;
589
EXCEPTION
590
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
591
END;
592
$$;
593

    
594

    
595
--
596
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
597
--
598

    
599
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
600
    LANGUAGE plpgsql STABLE STRICT
601
    AS $$
602
DECLARE
603
	default_sql text;
604
BEGIN
605
	SELECT adsrc
606
	FROM pg_attribute
607
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
608
	WHERE attrelid = col.table_ AND attname = col.name
609
	INTO STRICT default_sql
610
	;
611
	RETURN default_sql;
612
EXCEPTION
613
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
614
END;
615
$$;
616

    
617

    
618
--
619
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
620
--
621

    
622
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
623
    LANGUAGE sql STABLE
624
    AS $_$
625
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
626
$_$;
627

    
628

    
629
--
630
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
631
--
632

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

    
635

    
636
--
637
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
638
--
639

    
640
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
641
    LANGUAGE plpgsql STRICT
642
    AS $$
643
BEGIN
644
    PERFORM util.col_type(col);
645
    RETURN true;
646
EXCEPTION
647
    WHEN undefined_column THEN RETURN false;
648
END;
649
$$;
650

    
651

    
652
--
653
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
654
--
655

    
656
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
657
    LANGUAGE plpgsql STABLE STRICT
658
    AS $$
659
DECLARE
660
    prefix text := util.name(type)||'.';
661
BEGIN
662
    RETURN QUERY
663
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
664
        FROM util.col_names(type) f (name_);
665
END;
666
$$;
667

    
668

    
669
--
670
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
671
--
672

    
673
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
674
    LANGUAGE plpgsql STABLE STRICT
675
    AS $_$
676
BEGIN
677
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
678
END;
679
$_$;
680

    
681

    
682
--
683
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
684
--
685

    
686
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
687
    LANGUAGE sql STABLE STRICT
688
    AS $_$
689
SELECT attname::text
690
FROM pg_attribute
691
WHERE attrelid = $1 AND attnum >= 1
692
ORDER BY attnum
693
$_$;
694

    
695

    
696
--
697
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
698
--
699

    
700
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
701
    LANGUAGE plpgsql STABLE STRICT
702
    AS $$
703
DECLARE
704
    type regtype;
705
BEGIN
706
    SELECT atttypid FROM pg_attribute
707
    WHERE attrelid = col.table_ AND attname = col.name
708
    INTO STRICT type
709
    ;
710
    RETURN type;
711
EXCEPTION
712
    WHEN no_data_found THEN
713
        RAISE undefined_column USING MESSAGE =
714
            concat('undefined column: ', col.name);
715
END;
716
$$;
717

    
718

    
719
--
720
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
721
--
722

    
723
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
724
    LANGUAGE sql IMMUTABLE STRICT
725
    AS $_$
726
SELECT position($1 in $2) > 0 /*1-based offset*/
727
$_$;
728

    
729

    
730
--
731
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
732
--
733

    
734
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
735
    LANGUAGE plpgsql STRICT
736
    AS $$
737
BEGIN
738
    PERFORM util.eval(sql);
739
EXCEPTION
740
    WHEN duplicate_table  THEN NULL;
741
    WHEN duplicate_column THEN NULL;
742
END;
743
$$;
744

    
745

    
746
--
747
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
748
--
749

    
750
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
751

    
752

    
753
--
754
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
755
--
756

    
757
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
758
    LANGUAGE sql STRICT
759
    AS $_$
760
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
761
$_$;
762

    
763

    
764
--
765
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
766
--
767

    
768
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS 'idempotent';
769

    
770

    
771
--
772
-- Name: drop_table(text); Type: FUNCTION; Schema: util; Owner: -
773
--
774

    
775
CREATE FUNCTION drop_table(table_ text) RETURNS void
776
    LANGUAGE sql STRICT
777
    AS $_$
778
SELECT util.eval($$DROP TABLE IF EXISTS $$||$1)
779
$_$;
780

    
781

    
782
--
783
-- Name: FUNCTION drop_table(table_ text); Type: COMMENT; Schema: util; Owner: -
784
--
785

    
786
COMMENT ON FUNCTION drop_table(table_ text) IS 'idempotent';
787

    
788

    
789
--
790
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
791
--
792

    
793
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
794
    LANGUAGE sql IMMUTABLE STRICT
795
    AS $_$
796
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
797
$_$;
798

    
799

    
800
--
801
-- Name: eval(text); Type: FUNCTION; Schema: util; Owner: -
802
--
803

    
804
CREATE FUNCTION eval(sql text) RETURNS void
805
    LANGUAGE plpgsql STRICT
806
    AS $$
807
BEGIN
808
    RAISE NOTICE '%', sql;
809
    EXECUTE sql;
810
END;
811
$$;
812

    
813

    
814
--
815
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
816
--
817

    
818
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
819
    LANGUAGE plpgsql
820
    AS $$
821
DECLARE
822
	ret_val ret_type_null%TYPE;
823
BEGIN
824
	RAISE NOTICE '%', sql;
825
	EXECUTE sql INTO STRICT ret_val;
826
	RETURN ret_val;
827
END;
828
$$;
829

    
830

    
831
--
832
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
833
--
834

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

    
837

    
838
--
839
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
840
--
841

    
842
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
843
    LANGUAGE sql
844
    AS $_$
845
SELECT util.eval2val($$SELECT $$||$1, $2)
846
$_$;
847

    
848

    
849
--
850
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
851
--
852

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

    
855

    
856
--
857
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
858
--
859

    
860
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
861
    LANGUAGE sql
862
    AS $_$
863
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
864
$_$;
865

    
866

    
867
--
868
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
869
--
870

    
871
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS 'sql: can be NULL, which will be passed through
872
ret_type_null: NULL::ret_type';
873

    
874

    
875
--
876
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
877
--
878

    
879
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
880
    LANGUAGE sql STABLE STRICT
881
    AS $_$
882
SELECT col_name
883
FROM unnest($2) s (col_name)
884
WHERE util.col_exists(($1, col_name))
885
$_$;
886

    
887

    
888
--
889
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
890
--
891

    
892
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
893
    LANGUAGE plpgsql STRICT
894
    AS $_$
895
DECLARE
896
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
897
$$||query;
898
BEGIN
899
	EXECUTE mk_view;
900
EXCEPTION
901
WHEN invalid_table_definition THEN
902
	IF SQLERRM = 'cannot drop columns from view'
903
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
904
	THEN
905
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
906
		EXECUTE mk_view;
907
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
908
	END IF;
909
END;
910
$_$;
911

    
912

    
913
--
914
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
915
--
916

    
917
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS 'idempotent';
918

    
919

    
920
--
921
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
922
--
923

    
924
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
925
    LANGUAGE sql IMMUTABLE STRICT
926
    AS $_$
927
SELECT substring($2 for length($1)) = $1
928
$_$;
929

    
930

    
931
--
932
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
933
--
934

    
935
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
936
    LANGUAGE sql STABLE STRICT
937
    AS $_$
938
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
939
$_$;
940

    
941

    
942
--
943
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
944
--
945

    
946
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
947
    LANGUAGE sql IMMUTABLE STRICT
948
    AS $_$
949
SELECT $1 || $3 || $2
950
$_$;
951

    
952

    
953
--
954
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
955
--
956

    
957
CREATE FUNCTION map_filter_insert() RETURNS trigger
958
    LANGUAGE plpgsql
959
    AS $$
960
BEGIN
961
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
962
	RETURN new;
963
END;
964
$$;
965

    
966

    
967
--
968
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
969
--
970

    
971
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
972
    LANGUAGE plpgsql STABLE STRICT
973
    AS $_$
974
DECLARE
975
    value text;
976
BEGIN
977
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
978
        INTO value USING key;
979
    RETURN value;
980
END;
981
$_$;
982

    
983

    
984
--
985
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
986
--
987

    
988
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
989
    LANGUAGE plpgsql STABLE STRICT
990
    AS $_$
991
BEGIN
992
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
993
END;
994
$_$;
995

    
996

    
997
--
998
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
999
--
1000

    
1001
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
1002
    LANGUAGE sql STRICT
1003
    AS $_$
1004
SELECT util.create_if_not_exists($$
1005
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
1006
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
1007
||quote_literal($2)||$$;
1008
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS 'constant';
1009
$$)
1010
$_$;
1011

    
1012

    
1013
--
1014
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
1015
--
1016

    
1017
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS 'idempotent';
1018

    
1019

    
1020
--
1021
-- Name: mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1022
--
1023

    
1024
CREATE FUNCTION mk_derived_col(col col_ref, expr text) RETURNS void
1025
    LANGUAGE plpgsql STRICT
1026
    AS $_$
1027
DECLARE
1028
    type regtype = util.typeof(expr, col.table_::text::regtype);
1029
    col_name_sql text = quote_ident(col.name);
1030
BEGIN
1031
    PERFORM util.create_if_not_exists($$
1032
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;
1033
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
1034
$$||expr||$$;
1035
$$);
1036
END;
1037
$_$;
1038

    
1039

    
1040
--
1041
-- Name: FUNCTION mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1042
--
1043

    
1044
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text) IS 'idempotent';
1045

    
1046

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

    
1051
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
1052
    LANGUAGE sql STRICT
1053
    AS $_$
1054
SELECT util.create_if_not_exists($$
1055
CREATE TABLE $$||$1||$$
1056
(
1057
    LIKE util.map INCLUDING ALL
1058
);
1059

    
1060
CREATE TRIGGER map_filter_insert
1061
  BEFORE INSERT
1062
  ON $$||$1||$$
1063
  FOR EACH ROW
1064
  EXECUTE PROCEDURE util.map_filter_insert();
1065
$$)
1066
$_$;
1067

    
1068

    
1069
--
1070
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
1071
--
1072

    
1073
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
1074
    LANGUAGE sql STRICT
1075
    AS $_$
1076
SELECT util.mk_const_col(($1, 'source'), util.table_schema($1))
1077
$_$;
1078

    
1079

    
1080
--
1081
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1082
--
1083

    
1084
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS 'idempotent';
1085

    
1086

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

    
1091
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
1092
    LANGUAGE plpgsql STRICT
1093
    AS $_$
1094
BEGIN
1095
	EXECUTE $$
1096
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1097
  RETURNS SETOF $$||view_||$$ AS
1098
$BODY1$
1099
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$
1100
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN COALESCE($2, 0)+1 AND COALESCE(COALESCE($2, 0)+1 + $1 - 1, 2147483647)
1101
$BODY1$
1102
  LANGUAGE sql STABLE
1103
  COST 100
1104
  ROWS 1000
1105
$$;
1106
-- Also create subset function which turns off enable_sort
1107
	EXECUTE $$
1108
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
1109
  RETURNS SETOF $$||view_||$$
1110
  SET enable_sort TO 'off'
1111
  AS
1112
$BODY1$
1113
SELECT * FROM $$||util.type_qual_name(view_::text::regtype)||$$($2, $3)
1114
$BODY1$
1115
  LANGUAGE sql STABLE
1116
  COST 100
1117
  ROWS 1000
1118
;
1119
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
1120
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
1121
If you want to run EXPLAIN and get expanded output, use the regular subset
1122
function instead. (When a config param is set on a function, EXPLAIN produces
1123
just a function scan.)
1124
';
1125
$$;
1126
END;
1127
$_$;
1128

    
1129

    
1130
--
1131
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
1132
--
1133

    
1134
CREATE FUNCTION name(type regtype) RETURNS text
1135
    LANGUAGE sql STABLE STRICT
1136
    AS $_$
1137
SELECT typname::text FROM pg_type WHERE oid = $1
1138
$_$;
1139

    
1140

    
1141
--
1142
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1143
--
1144

    
1145
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
1146
    LANGUAGE sql IMMUTABLE
1147
    AS $_$
1148
SELECT $1 IS NOT NULL AND array_length($1, 1)/*ARRAY[]->NULL*/ IS NOT NULL
1149
$_$;
1150

    
1151

    
1152
--
1153
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
1154
--
1155

    
1156
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
1157
    LANGUAGE sql IMMUTABLE
1158
    AS $_$
1159
SELECT $1 IS NOT NULL
1160
$_$;
1161

    
1162

    
1163
--
1164
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
1165
--
1166

    
1167
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
1168
    LANGUAGE plpgsql IMMUTABLE STRICT
1169
    AS $$
1170
BEGIN
1171
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
1172
END;
1173
$$;
1174

    
1175

    
1176
--
1177
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1178
--
1179

    
1180
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
1181
    LANGUAGE sql STRICT
1182
    AS $_$
1183
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1184
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
1185
FROM util.col_names($1::text::regtype) f (name)
1186
$_$;
1187

    
1188

    
1189
--
1190
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
1191
--
1192

    
1193
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS 'idempotent';
1194

    
1195

    
1196
--
1197
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
1198
--
1199

    
1200
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
1201
    LANGUAGE sql STRICT
1202
    AS $_$
1203
SELECT util.drop_table($1);
1204
SELECT util.mk_map_table($1);
1205
$_$;
1206

    
1207

    
1208
--
1209
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
1210
--
1211

    
1212
CREATE FUNCTION search_path_append(schemas text) RETURNS void
1213
    LANGUAGE sql STRICT
1214
    AS $_$
1215
SELECT util.eval(
1216
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
1217
$_$;
1218

    
1219

    
1220
--
1221
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1222
--
1223

    
1224
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
1225
    LANGUAGE plpgsql STRICT
1226
    AS $_$
1227
DECLARE
1228
    old text[] = ARRAY(SELECT util.col_names(table_));
1229
    new text[] = ARRAY(SELECT util.map_values(names));
1230
BEGIN
1231
    old = old[1:array_length(new, 1)]; -- truncate to same length
1232
    PERFORM util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
1233
        ||quote_ident(key)||$$ TO $$||quote_ident(value))
1234
    FROM each(hstore(old, new))
1235
    WHERE value != key -- not same name
1236
    ;
1237
END;
1238
$_$;
1239

    
1240

    
1241
--
1242
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1243
--
1244

    
1245
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS 'idempotent';
1246

    
1247

    
1248
--
1249
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1250
--
1251

    
1252
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
1253
    LANGUAGE plpgsql STRICT
1254
    AS $_$
1255
DECLARE
1256
	row_ util.map;
1257
BEGIN
1258
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
1259
	LOOP
1260
		PERFORM util.mk_const_col((table_, row_."to"),
1261
			substring(row_."from" from 2));
1262
	END LOOP;
1263
	
1264
	PERFORM util.set_col_names(table_, names);
1265
END;
1266
$_$;
1267

    
1268

    
1269
--
1270
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1271
--
1272

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

    
1276

    
1277
--
1278
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
1279
--
1280

    
1281
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
1282
    LANGUAGE plpgsql STRICT
1283
    AS $_$
1284
DECLARE
1285
    sql text = $$ALTER TABLE $$||table_||$$
1286
$$||NULLIF(array_to_string(ARRAY(
1287
    SELECT
1288
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
1289
    ||$$ USING $$||col_name_sql||$$::$$||target_type
1290
    FROM
1291
    (
1292
        SELECT
1293
          quote_ident(col_name) AS col_name_sql
1294
        , util.col_type((table_, col_name)) AS curr_type
1295
        , type AS target_type
1296
        FROM unnest(col_casts)
1297
    ) s
1298
    WHERE curr_type != target_type
1299
), '
1300
, '), '');
1301
BEGIN
1302
    RAISE NOTICE '%', sql;
1303
    EXECUTE COALESCE(sql, '');
1304
END;
1305
$_$;
1306

    
1307

    
1308
--
1309
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
1310
--
1311

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

    
1314

    
1315
--
1316
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
1317
--
1318

    
1319
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
1320
    LANGUAGE plpgsql STABLE STRICT
1321
    AS $_$
1322
DECLARE
1323
    hstore hstore;
1324
BEGIN
1325
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
1326
        table_||$$))$$ INTO STRICT hstore;
1327
    RETURN hstore;
1328
END;
1329
$_$;
1330

    
1331

    
1332
--
1333
-- Name: table_schema(regclass); Type: FUNCTION; Schema: util; Owner: -
1334
--
1335

    
1336
CREATE FUNCTION table_schema(table_ regclass) RETURNS text
1337
    LANGUAGE sql STABLE STRICT
1338
    AS $_$
1339
SELECT nspname::text FROM pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class WHERE oid = $1)
1340
$_$;
1341

    
1342

    
1343
--
1344
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
1345
--
1346

    
1347
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
1348
    LANGUAGE plpgsql STRICT
1349
    AS $_$
1350
DECLARE
1351
    row record;
1352
BEGIN
1353
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
1354
    LOOP
1355
        IF row.global_name != row.name THEN
1356
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
1357
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
1358
        END IF;
1359
    END LOOP;
1360
END;
1361
$_$;
1362

    
1363

    
1364
--
1365
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1366
--
1367

    
1368
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
1369

    
1370

    
1371
--
1372
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
1373
--
1374

    
1375
CREATE FUNCTION truncate(table_ regclass) RETURNS void
1376
    LANGUAGE plpgsql STRICT
1377
    AS $_$
1378
BEGIN
1379
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
1380
END;
1381
$_$;
1382

    
1383

    
1384
--
1385
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
1386
--
1387

    
1388
COMMENT ON FUNCTION truncate(table_ regclass) IS 'idempotent';
1389

    
1390

    
1391
--
1392
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
1393
--
1394

    
1395
CREATE FUNCTION try_create(sql text) RETURNS void
1396
    LANGUAGE plpgsql STRICT
1397
    AS $$
1398
BEGIN
1399
    PERFORM util.eval(sql);
1400
EXCEPTION
1401
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
1402
    WHEN undefined_column THEN NULL;
1403
    WHEN duplicate_column THEN NULL;
1404
END;
1405
$$;
1406

    
1407

    
1408
--
1409
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
1410
--
1411

    
1412
COMMENT ON FUNCTION try_create(sql text) IS 'idempotent';
1413

    
1414

    
1415
--
1416
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
1417
--
1418

    
1419
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
1420
    LANGUAGE sql STRICT
1421
    AS $_$
1422
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
1423
$_$;
1424

    
1425

    
1426
--
1427
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
1428
--
1429

    
1430
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS 'idempotent';
1431

    
1432

    
1433
--
1434
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
1435
--
1436

    
1437
CREATE FUNCTION type_qual(value anyelement) RETURNS text
1438
    LANGUAGE sql IMMUTABLE
1439
    AS $_$
1440
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
1441
$_$;
1442

    
1443

    
1444
--
1445
-- Name: type_qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
1446
--
1447

    
1448
CREATE FUNCTION type_qual_name(type regtype) RETURNS text
1449
    LANGUAGE sql STABLE STRICT
1450
    SET search_path TO pg_temp
1451
    AS $_$
1452
SELECT $1::text
1453
$_$;
1454

    
1455

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

    
1460
CREATE FUNCTION typeof(expr text, table_ regtype) RETURNS regtype
1461
    LANGUAGE plpgsql STABLE STRICT
1462
    AS $_$
1463
DECLARE
1464
    type regtype;
1465
BEGIN
1466
    EXECUTE $$SELECT pg_typeof($$||expr||$$) FROM (SELECT (NULL::$$||table_||
1467
    $$).*) _s$$ INTO STRICT type;
1468
    RETURN type;
1469
END;
1470
$_$;
1471

    
1472

    
1473
--
1474
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
1475
--
1476

    
1477
CREATE AGGREGATE all_same(anyelement) (
1478
    SFUNC = all_same_transform,
1479
    STYPE = anyarray,
1480
    FINALFUNC = all_same_final
1481
);
1482

    
1483

    
1484
--
1485
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
1486
--
1487

    
1488
COMMENT ON AGGREGATE all_same(anyelement) IS 'includes NULLs in comparison';
1489

    
1490

    
1491
--
1492
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
1493
--
1494

    
1495
CREATE AGGREGATE join_strs(text, text) (
1496
    SFUNC = join_strs_transform,
1497
    STYPE = text
1498
);
1499

    
1500

    
1501
--
1502
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
1503
--
1504

    
1505
CREATE OPERATOR -> (
1506
    PROCEDURE = map_get,
1507
    LEFTARG = regclass,
1508
    RIGHTARG = text
1509
);
1510

    
1511

    
1512
SET default_tablespace = '';
1513

    
1514
SET default_with_oids = false;
1515

    
1516
--
1517
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1518
--
1519

    
1520
CREATE TABLE map (
1521
    "from" text NOT NULL,
1522
    "to" text,
1523
    filter text,
1524
    notes text
1525
);
1526

    
1527

    
1528
--
1529
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
1530
--
1531

    
1532

    
1533

    
1534
--
1535
-- Name: map_pkey; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
1536
--
1537

    
1538
ALTER TABLE ONLY map
1539
    ADD CONSTRAINT map_pkey PRIMARY KEY ("from");
1540

    
1541

    
1542
--
1543
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
1544
--
1545

    
1546
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
1547

    
1548

    
1549
--
1550
-- PostgreSQL database dump complete
1551
--
1552

    
(17-17/27)