Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

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

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

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

    
74
--
75
-- Name: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
76
--
77

    
78
CREATE FUNCTION "%=="(left_ anyelement, right_ anyelement) RETURNS boolean
79
    LANGUAGE sql STABLE
80
    AS $_$
81
SELECT keys($1) = keys($2)
82
$_$;
83

    
84

    
85
--
86
-- Name: FUNCTION "%=="(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
87
--
88

    
89
COMMENT ON FUNCTION "%=="(left_ anyelement, right_ anyelement) IS '
90
needs to be declared STABLE instead of IMMUTABLE because it depends on the search_path (as described at http://vegpath.org/links/#PostgreSQL:%20Documentation:%209.3:%20Function%20Volatility%20Categories%20**)
91
';
92

    
93

    
94
--
95
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
96
--
97

    
98
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
99
    LANGUAGE sql IMMUTABLE
100
    AS $_$
101
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
102
$_$;
103

    
104

    
105
--
106
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
107
--
108

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

    
124

    
125
--
126
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
127
--
128

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

    
133

    
134
--
135
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
136
--
137

    
138
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
139
    LANGUAGE sql IMMUTABLE
140
    AS $_$
141
SELECT avg(value)
142
FROM
143
(VALUES
144
      ($1)
145
    , ($2)
146
    , ($3)
147
    , ($4)
148
    , ($5)
149
)
150
AS v (value)
151
$_$;
152

    
153

    
154
--
155
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
156
--
157

    
158
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
159
    LANGUAGE sql IMMUTABLE
160
    AS $_$
161
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)
162
FROM 
163
(
164
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
165
    UNION ALL
166
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
167
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
168
)
169
matches (g)
170
$_$;
171

    
172

    
173
--
174
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
175
--
176

    
177
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
178
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
181
FROM
182
(VALUES
183
      ($1)
184
    , ($2/60)
185
    , ($3/60/60)
186
)
187
AS v (value)
188
$_$;
189

    
190

    
191
--
192
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
193
--
194

    
195
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
196
    LANGUAGE sql IMMUTABLE
197
    AS $_$
198
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
199
$_$;
200

    
201

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

    
206
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
207
    LANGUAGE sql IMMUTABLE
208
    AS $_$
209
SELECT $1 = $2
210
$_$;
211

    
212

    
213
--
214
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: util; Owner: -
215
--
216

    
217
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
218
    LANGUAGE sql IMMUTABLE
219
    AS $_$
220
-- Fix dates after threshold date
221
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
222
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
223
$_$;
224

    
225

    
226
--
227
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
228
--
229

    
230
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
231
    LANGUAGE sql IMMUTABLE
232
    AS $_$
233
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
234
$_$;
235

    
236

    
237
--
238
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
239
--
240

    
241
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
242
    LANGUAGE sql IMMUTABLE
243
    AS $_$
244
SELECT util._if($1 != '', $2, $3)
245
$_$;
246

    
247

    
248
--
249
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
250
--
251

    
252
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
253
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
256
$_$;
257

    
258

    
259
--
260
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
261
--
262

    
263
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
264
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
267
$_$;
268

    
269

    
270
--
271
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
272
--
273

    
274
CREATE FUNCTION _label(label text, value text) RETURNS text
275
    LANGUAGE sql IMMUTABLE
276
    AS $_$
277
SELECT coalesce($1 || ': ', '') || $2
278
$_$;
279

    
280

    
281
--
282
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
283
--
284

    
285
CREATE FUNCTION _lowercase(value text) RETURNS text
286
    LANGUAGE sql IMMUTABLE
287
    AS $_$
288
SELECT lower($1)
289
$_$;
290

    
291

    
292
--
293
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
294
--
295

    
296
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
297
    LANGUAGE plpgsql IMMUTABLE STRICT
298
    AS $$
299
DECLARE
300
    result value%TYPE := util._map(map, value::text)::unknown;
301
BEGIN
302
    RETURN result;
303
END;
304
$$;
305

    
306

    
307
--
308
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
309
--
310

    
311
CREATE FUNCTION _map(map hstore, value text) RETURNS text
312
    LANGUAGE plpgsql IMMUTABLE STRICT
313
    AS $$
314
DECLARE
315
    match text := map -> value;
316
BEGIN
317
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
318
        match := map -> '*'; -- use default entry
319
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
320
        END IF;
321
    END IF;
322
    
323
    -- Interpret result
324
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
325
    ELSIF match = '*' THEN RETURN value;
326
    ELSE RETURN match;
327
    END IF;
328
END;
329
$$;
330

    
331

    
332
--
333
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
334
--
335

    
336
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
337
    LANGUAGE sql IMMUTABLE
338
    AS $_$
339
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
340
$_$;
341

    
342

    
343
--
344
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
345
--
346

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

    
381

    
382
--
383
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
384
--
385

    
386
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
387
    LANGUAGE sql IMMUTABLE
388
    AS $_$
389
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
390
$_$;
391

    
392

    
393
--
394
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
395
--
396

    
397
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
398
    LANGUAGE sql IMMUTABLE
399
    AS $_$
400
SELECT util.join_strs(value, ' ')
401
FROM
402
(
403
    SELECT *
404
    FROM
405
    (
406
        SELECT
407
        DISTINCT ON (value)
408
        *
409
        FROM
410
        (VALUES
411
              (1, $1)
412
            , (2, $2)
413
            , (3, $3)
414
            , (4, $4)
415
            , (5, $5)
416
            , (6, $6)
417
            , (7, $7)
418
            , (8, $8)
419
            , (9, $9)
420
            , (10, $10)
421
        )
422
        AS v (sort_order, value)
423
        WHERE value IS NOT NULL
424
    )
425
    AS v
426
    ORDER BY sort_order
427
)
428
AS v
429
$_$;
430

    
431

    
432
--
433
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
434
--
435

    
436
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
437
    LANGUAGE sql IMMUTABLE
438
    AS $_$
439
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
440
$_$;
441

    
442

    
443
--
444
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
445
--
446

    
447
CREATE FUNCTION _not(value boolean) RETURNS boolean
448
    LANGUAGE sql IMMUTABLE
449
    AS $_$
450
SELECT NOT $1
451
$_$;
452

    
453

    
454
--
455
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
456
--
457

    
458
CREATE FUNCTION _now() RETURNS timestamp with time zone
459
    LANGUAGE sql STABLE
460
    AS $$
461
SELECT now()
462
$$;
463

    
464

    
465
--
466
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
467
--
468

    
469
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
470
    LANGUAGE sql IMMUTABLE
471
    AS $_$
472
SELECT util."_nullIf"($1, $2, $3::util.datatype)
473
$_$;
474

    
475

    
476
--
477
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
478
--
479

    
480
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
481
    LANGUAGE plpgsql IMMUTABLE
482
    AS $$
483
DECLARE
484
    type util.datatype NOT NULL := type; -- add NOT NULL
485
BEGIN
486
    IF type = 'str' THEN RETURN nullif(value::text, "null");
487
    -- Invalid value is ignored, but invalid null value generates error
488
    ELSIF type = 'float' THEN
489
        DECLARE
490
            -- Outside the try block so that invalid null value generates error
491
            "null" double precision := "null"::double precision;
492
        BEGIN
493
            RETURN nullif(value::double precision, "null");
494
        EXCEPTION
495
            WHEN data_exception THEN RETURN value; -- ignore invalid value
496
        END;
497
    END IF;
498
END;
499
$$;
500

    
501

    
502
--
503
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
504
--
505

    
506
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
507
    LANGUAGE sql IMMUTABLE
508
    AS $_$
509
SELECT bool_or(value)
510
FROM
511
(VALUES
512
      ($1)
513
    , ($2)
514
    , ($3)
515
    , ($4)
516
    , ($5)
517
)
518
AS v (value)
519
$_$;
520

    
521

    
522
--
523
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
524
--
525

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

    
530

    
531
--
532
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
533
--
534

    
535
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
536
    LANGUAGE sql IMMUTABLE
537
    AS $_$
538
SELECT $2 - $1
539
$_$;
540

    
541

    
542
--
543
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
544
--
545

    
546
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
547
    LANGUAGE sql IMMUTABLE
548
    AS $_$
549
SELECT regexp_split_to_table($1, $2)
550
$_$;
551

    
552

    
553
--
554
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
555
--
556

    
557
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
558
    LANGUAGE sql STABLE
559
    AS $_$
560
SELECT util.derived_cols($1, $2)
561
UNION
562
SELECT util.eval2set($$
563
SELECT col
564
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
565
JOIN $$||$2||$$ ON "to" = col
566
WHERE "from" LIKE ':%'
567
$$, NULL::text)
568
$_$;
569

    
570

    
571
--
572
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
573
--
574

    
575
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
576
gets table_''s added columns (all the columns not in the original data)
577
';
578

    
579

    
580
--
581
-- Name: all_same_final(anyarray); Type: FUNCTION; Schema: util; Owner: -
582
--
583

    
584
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
585
    LANGUAGE sql IMMUTABLE
586
    AS $_$
587
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
588
$_$;
589

    
590

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

    
595
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
596
    LANGUAGE plpgsql IMMUTABLE
597
    AS $$
598
DECLARE
599
	value_cmp         state%TYPE = ARRAY[value];
600
	state             state%TYPE = COALESCE(state, value_cmp);
601
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
602
BEGIN
603
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
604
END;
605
$$;
606

    
607

    
608
--
609
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
610
--
611

    
612
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
613
    LANGUAGE sql
614
    AS $_$
615
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
616
$_$;
617

    
618

    
619
--
620
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
621
--
622

    
623
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
624
    LANGUAGE sql
625
    AS $_$
626
SELECT util.set_comment($1, concat(util.comment($1), $2))
627
$_$;
628

    
629

    
630
--
631
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
632
--
633

    
634
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
635
comment: must start and end with a newline
636
';
637

    
638

    
639
--
640
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
641
--
642

    
643
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
644
    LANGUAGE sql IMMUTABLE
645
    AS $_$
646
SELECT pg_catalog.array_fill($1, ARRAY[$2])
647
$_$;
648

    
649

    
650
--
651
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
652
--
653

    
654
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
655
    LANGUAGE sql IMMUTABLE
656
    AS $_$
657
SELECT util.array_length($1, 1)
658
$_$;
659

    
660

    
661
--
662
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
663
--
664

    
665
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
666
    LANGUAGE sql IMMUTABLE
667
    AS $_$
668
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
669
$_$;
670

    
671

    
672
--
673
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
674
--
675

    
676
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
677
returns 0 instead of NULL for empty arrays
678
';
679

    
680

    
681
--
682
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
683
--
684

    
685
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
686
    LANGUAGE sql STABLE
687
    AS $_$
688
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
689
$_$;
690

    
691

    
692
--
693
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
694
--
695

    
696
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
697
    LANGUAGE plpgsql STRICT
698
    AS $_$
699
BEGIN
700
    -- not yet clustered (ARRAY[] compares NULLs literally)
701
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
702
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
703
    END IF;
704
END;
705
$_$;
706

    
707

    
708
--
709
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
710
--
711

    
712
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
713
idempotent
714
';
715

    
716

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

    
721
CREATE FUNCTION col__min(col col_ref) RETURNS integer
722
    LANGUAGE sql STABLE
723
    AS $_$
724
SELECT util.eval2val($$
725
SELECT $$||quote_ident($1.name)||$$
726
FROM $$||$1.table_||$$
727
ORDER BY $$||quote_ident($1.name)||$$ ASC
728
LIMIT 1
729
$$, NULL::integer)
730
$_$;
731

    
732

    
733
--
734
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
735
--
736

    
737
CREATE FUNCTION col_comment(col col_ref) RETURNS text
738
    LANGUAGE plpgsql STABLE STRICT
739
    AS $$
740
DECLARE
741
	comment text;
742
BEGIN
743
	SELECT description
744
	FROM pg_attribute
745
	LEFT JOIN pg_description ON objoid = attrelid
746
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
747
	WHERE attrelid = col.table_ AND attname = col.name
748
	INTO STRICT comment
749
	;
750
	RETURN comment;
751
EXCEPTION
752
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
753
END;
754
$$;
755

    
756

    
757
--
758
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
759
--
760

    
761
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
762
    LANGUAGE plpgsql STABLE STRICT
763
    AS $$
764
DECLARE
765
	default_sql text;
766
BEGIN
767
	SELECT adsrc
768
	FROM pg_attribute
769
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
770
	WHERE attrelid = col.table_ AND attname = col.name
771
	INTO STRICT default_sql
772
	;
773
	RETURN default_sql;
774
EXCEPTION
775
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
776
END;
777
$$;
778

    
779

    
780
--
781
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
782
--
783

    
784
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
785
    LANGUAGE sql STABLE
786
    AS $_$
787
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
788
$_$;
789

    
790

    
791
--
792
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
793
--
794

    
795
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
796
ret_type_null: NULL::ret_type
797
';
798

    
799

    
800
--
801
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
802
--
803

    
804
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
805
    LANGUAGE plpgsql STRICT
806
    AS $$
807
BEGIN
808
    PERFORM util.col_type(col);
809
    RETURN true;
810
EXCEPTION
811
    WHEN undefined_column THEN RETURN false;
812
END;
813
$$;
814

    
815

    
816
--
817
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
818
--
819

    
820
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
821
    LANGUAGE plpgsql STABLE STRICT
822
    AS $$
823
DECLARE
824
    prefix text := util.name(type)||'.';
825
BEGIN
826
    RETURN QUERY
827
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
828
        FROM util.col_names(type) f (name_);
829
END;
830
$$;
831

    
832

    
833
--
834
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
835
--
836

    
837
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
838
    LANGUAGE sql STABLE
839
    AS $_$
840
SELECT attname::text
841
FROM pg_attribute
842
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
843
ORDER BY attnum
844
$_$;
845

    
846

    
847
--
848
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
849
--
850

    
851
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
852
    LANGUAGE plpgsql STABLE STRICT
853
    AS $_$
854
BEGIN
855
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
856
END;
857
$_$;
858

    
859

    
860
--
861
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
862
--
863

    
864
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
865
    LANGUAGE plpgsql STABLE STRICT
866
    AS $$
867
DECLARE
868
    type regtype;
869
BEGIN
870
    SELECT atttypid FROM pg_attribute
871
    WHERE attrelid = col.table_ AND attname = col.name
872
    INTO STRICT type
873
    ;
874
    RETURN type;
875
EXCEPTION
876
    WHEN no_data_found THEN
877
        RAISE undefined_column USING MESSAGE =
878
            concat('undefined column: ', col.name);
879
END;
880
$$;
881

    
882

    
883
--
884
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
885
--
886

    
887
CREATE FUNCTION comment(element oid) RETURNS text
888
    LANGUAGE sql STABLE
889
    AS $_$
890
SELECT description FROM pg_description WHERE objoid = $1
891
$_$;
892

    
893

    
894
--
895
-- Name: concat_esc(text, text); Type: FUNCTION; Schema: util; Owner: -
896
--
897

    
898
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
899
    LANGUAGE sql IMMUTABLE
900
    AS $_$
901
SELECT util.esc_name__append($2, $1)
902
$_$;
903

    
904

    
905
--
906
-- Name: contains(text, text); Type: FUNCTION; Schema: util; Owner: -
907
--
908

    
909
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
910
    LANGUAGE sql IMMUTABLE
911
    AS $_$
912
SELECT position($1 in $2) > 0 /*1-based offset*/
913
$_$;
914

    
915

    
916
--
917
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
918
--
919

    
920
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
921
    LANGUAGE sql
922
    AS $_$
923
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
924
$_$;
925

    
926

    
927
--
928
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
929
--
930

    
931
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
932
    LANGUAGE sql
933
    AS $_$
934
SELECT util.materialize_view($2, $1)
935
$_$;
936

    
937

    
938
--
939
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
940
--
941

    
942
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
943
    LANGUAGE plpgsql STRICT
944
    AS $$
945
BEGIN
946
	PERFORM util.eval(sql);
947
EXCEPTION
948
WHEN duplicate_table THEN NULL;
949
WHEN duplicate_object THEN NULL; -- e.g. constraint
950
WHEN duplicate_column THEN NULL;
951
WHEN duplicate_function THEN NULL;
952
WHEN invalid_table_definition THEN
953
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
954
	ELSE RAISE;
955
	END IF;
956
END;
957
$$;
958

    
959

    
960
--
961
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
962
--
963

    
964
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
965
idempotent
966
';
967

    
968

    
969
--
970
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
971
--
972

    
973
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
974
    LANGUAGE sql STABLE
975
    AS $$
976
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
977
$$;
978

    
979

    
980
--
981
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
982
--
983

    
984
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
985
    LANGUAGE sql IMMUTABLE
986
    AS $_$
987
SELECT util.raise('NOTICE', 'returns: '
988
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
989
SELECT $1;
990
$_$;
991

    
992

    
993
--
994
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
995
--
996

    
997
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
998
    LANGUAGE sql IMMUTABLE
999
    AS $_$
1000
/* newline before so the query starts at the beginning of the line.
1001
newline after to visually separate queries from one another. */
1002
SELECT util.raise('NOTICE', $$
1003
$$||util.runnable_sql($1)||$$
1004
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1005
$_$;
1006

    
1007

    
1008
--
1009
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1010
--
1011

    
1012
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1013
    LANGUAGE sql STABLE
1014
    AS $_$
1015
SELECT util.eval2set($$
1016
SELECT col
1017
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1018
LEFT JOIN $$||$2||$$ ON "to" = col
1019
WHERE "from" IS NULL
1020
$$, NULL::text)
1021
$_$;
1022

    
1023

    
1024
--
1025
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1026
--
1027

    
1028
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1029
gets table_''s derived columns (all the columns not in the names table)
1030
';
1031

    
1032

    
1033
--
1034
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1035
--
1036

    
1037
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1038
    LANGUAGE sql
1039
    AS $_$
1040
-- create a diff when the # of copies of a row differs between the tables
1041
SELECT util.to_freq($1);
1042
SELECT util.to_freq($2);
1043
SELECT util.eval($$ALTER TABLE $$||util.typeof($3)||$$ ADD COLUMN copies bigint NOT NULL$$);
1044

    
1045
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1046
$_$;
1047

    
1048

    
1049
--
1050
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1051
--
1052

    
1053
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1054
usage:
1055
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1056

    
1057
col_type_null (*required*): NULL::shared_base_type
1058
';
1059

    
1060

    
1061
--
1062
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1063
--
1064

    
1065
CREATE FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean DEFAULT false, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1066
    LANGUAGE plpgsql
1067
    SET search_path TO pg_temp
1068
    AS $_$
1069
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1070
changes of search_path (schema elements are bound at inline time rather than
1071
runtime) */
1072
/* function option search_path is needed to limit the effects of
1073
`SET LOCAL search_path` to the current function */
1074
BEGIN
1075
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1076
	
1077
	PERFORM util.mk_keys_func(pg_typeof($3));
1078
	RETURN QUERY
1079
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1080
$$/* need to explicitly cast each side to the return type because this does not
1081
happen automatically even when an implicit cast is available */
1082
  left_::$$||util.typeof($3)||$$
1083
, right_::$$||util.typeof($3)
1084
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1085
the *same* base type, *even though* this is optional when using a custom %== */
1086
, util._if($4, $$true/*= CROSS JOIN*/$$,
1087
$$ left_::$$||util.typeof($3)||$$
1088
%== right_::$$||util.typeof($3)||$$
1089
	-- refer to EXPLAIN output for expansion of %==$$
1090
)), $3)
1091
	;
1092
END;
1093
$_$;
1094

    
1095

    
1096
--
1097
-- Name: FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1098
--
1099

    
1100
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1101
col_type_null (*required*): NULL::col_type
1102
single_row: whether the tables consist of a single row, which should be
1103
	displayed side-by-side
1104

    
1105
to match up rows using a subset of the columns, create a custom keys() function
1106
which returns this subset as a record:
1107
-- note that OUT parameters for the returned fields are *not* needed
1108
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1109
  RETURNS record AS
1110
$BODY$
1111
SELECT ($1.key_field_0, $1.key_field_1)
1112
$BODY$
1113
  LANGUAGE sql IMMUTABLE
1114
  COST 100;
1115

    
1116

    
1117
to run EXPLAIN on the FULL JOIN query:
1118
# run this function
1119
# look for a NOTICE containing the expanded query that it ran
1120
# run EXPLAIN on this expanded query
1121
';
1122

    
1123

    
1124
--
1125
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1126
--
1127

    
1128
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1129
    LANGUAGE sql
1130
    AS $_$
1131
SELECT * FROM util.diff($1::text, $2::text, $3,
1132
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1133
$_$;
1134

    
1135

    
1136
--
1137
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1138
--
1139

    
1140
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1141
helper function used by diff(regclass, regclass)
1142

    
1143
usage:
1144
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1145

    
1146
col_type_null (*required*): NULL::shared_base_type
1147
';
1148

    
1149

    
1150
--
1151
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1152
--
1153

    
1154
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1155
    LANGUAGE sql
1156
    AS $_$
1157
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1158
$_$;
1159

    
1160

    
1161
--
1162
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1163
--
1164

    
1165
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1166
idempotent
1167
';
1168

    
1169

    
1170
--
1171
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1172
--
1173

    
1174
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1175
    LANGUAGE sql
1176
    AS $_$
1177
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1178
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1179
$_$;
1180

    
1181

    
1182
--
1183
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1184
--
1185

    
1186
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1187
idempotent
1188
';
1189

    
1190

    
1191
--
1192
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1193
--
1194

    
1195
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1196
    LANGUAGE sql
1197
    AS $_$
1198
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1199
included in the debug SQL */
1200
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1201
$_$;
1202

    
1203

    
1204
--
1205
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1206
--
1207

    
1208
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1209
    LANGUAGE sql
1210
    AS $_$
1211
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1212
||util._if($3, $$ CASCADE$$, ''::text))
1213
$_$;
1214

    
1215

    
1216
--
1217
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1218
--
1219

    
1220
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1221
idempotent
1222
';
1223

    
1224

    
1225
--
1226
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1227
--
1228

    
1229
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1230
    LANGUAGE sql
1231
    AS $_$
1232
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1233
$_$;
1234

    
1235

    
1236
--
1237
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1238
--
1239

    
1240
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1241
    LANGUAGE sql
1242
    AS $_$
1243
SELECT util.drop_relation(relation, $3)
1244
FROM util.show_relations_like($1, $2) relation
1245
;
1246
SELECT NULL::void; -- don't fold away functions called in previous query
1247
$_$;
1248

    
1249

    
1250
--
1251
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1252
--
1253

    
1254
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1255
    LANGUAGE sql
1256
    AS $_$
1257
SELECT util.drop_relation('TABLE', $1, $2)
1258
$_$;
1259

    
1260

    
1261
--
1262
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1263
--
1264

    
1265
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1266
idempotent
1267
';
1268

    
1269

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

    
1274
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1275
    LANGUAGE sql
1276
    AS $_$
1277
SELECT util.drop_relation('VIEW', $1, $2)
1278
$_$;
1279

    
1280

    
1281
--
1282
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1283
--
1284

    
1285
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1286
idempotent
1287
';
1288

    
1289

    
1290
--
1291
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1292
--
1293

    
1294
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1295
    LANGUAGE sql IMMUTABLE
1296
    AS $_$
1297
SELECT util.array_fill($1, 0)
1298
$_$;
1299

    
1300

    
1301
--
1302
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1303
--
1304

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

    
1309

    
1310
--
1311
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1312
--
1313

    
1314
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1315
    LANGUAGE sql IMMUTABLE
1316
    AS $_$
1317
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1318
$_$;
1319

    
1320

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

    
1325
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1326
    LANGUAGE sql IMMUTABLE
1327
    AS $_$
1328
SELECT regexp_replace($2, '("?)$', $1||'\1')
1329
$_$;
1330

    
1331

    
1332
--
1333
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1334
--
1335

    
1336
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1337
    LANGUAGE plpgsql
1338
    AS $$
1339
BEGIN
1340
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1341
	EXECUTE sql;
1342
END;
1343
$$;
1344

    
1345

    
1346
--
1347
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1348
--
1349

    
1350
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1351
    LANGUAGE plpgsql
1352
    AS $$
1353
BEGIN
1354
	PERFORM util.debug_print_sql(sql);
1355
	RETURN QUERY EXECUTE sql;
1356
END;
1357
$$;
1358

    
1359

    
1360
--
1361
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1362
--
1363

    
1364
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1365
col_type_null (*required*): NULL::col_type
1366
';
1367

    
1368

    
1369
--
1370
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1371
--
1372

    
1373
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1374
    LANGUAGE plpgsql
1375
    AS $$
1376
BEGIN
1377
	PERFORM util.debug_print_sql(sql);
1378
	RETURN QUERY EXECUTE sql;
1379
END;
1380
$$;
1381

    
1382

    
1383
--
1384
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1385
--
1386

    
1387
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1388
    LANGUAGE plpgsql
1389
    AS $$
1390
BEGIN
1391
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1392
	RETURN QUERY EXECUTE sql;
1393
END;
1394
$$;
1395

    
1396

    
1397
--
1398
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1399
--
1400

    
1401
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1402
    LANGUAGE plpgsql STABLE
1403
    AS $$
1404
DECLARE
1405
	ret_val ret_type_null%TYPE;
1406
BEGIN
1407
	PERFORM util.debug_print_sql(sql);
1408
	EXECUTE sql INTO STRICT ret_val;
1409
	RETURN ret_val;
1410
END;
1411
$$;
1412

    
1413

    
1414
--
1415
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1416
--
1417

    
1418
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1419
ret_type_null: NULL::ret_type
1420
';
1421

    
1422

    
1423
--
1424
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1425
--
1426

    
1427
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1428
    LANGUAGE sql
1429
    AS $_$
1430
SELECT util.eval2val($$SELECT $$||$1, $2)
1431
$_$;
1432

    
1433

    
1434
--
1435
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1436
--
1437

    
1438
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1439
ret_type_null: NULL::ret_type
1440
';
1441

    
1442

    
1443
--
1444
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1445
--
1446

    
1447
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1448
    LANGUAGE sql
1449
    AS $_$
1450
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1451
$_$;
1452

    
1453

    
1454
--
1455
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1456
--
1457

    
1458
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1459
sql: can be NULL, which will be passed through
1460
ret_type_null: NULL::ret_type
1461
';
1462

    
1463

    
1464
--
1465
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1466
--
1467

    
1468
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1469
    LANGUAGE sql STABLE
1470
    AS $_$
1471
SELECT col_name
1472
FROM unnest($2) s (col_name)
1473
WHERE util.col_exists(($1, col_name))
1474
$_$;
1475

    
1476

    
1477
--
1478
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1479
--
1480

    
1481
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1482
    LANGUAGE sql
1483
    AS $_$
1484
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1485
$_$;
1486

    
1487

    
1488
--
1489
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1490
--
1491

    
1492
CREATE FUNCTION explain2notice(sql text) RETURNS void
1493
    LANGUAGE sql
1494
    AS $_$
1495
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1496
$_$;
1497

    
1498

    
1499
--
1500
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1501
--
1502

    
1503
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1504
    LANGUAGE sql
1505
    AS $_$
1506
-- newline before and after to visually separate it from other debug info
1507
SELECT $$
1508
EXPLAIN:
1509
$$||util.explain2str($1)||$$
1510
$$
1511
$_$;
1512

    
1513

    
1514
--
1515
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1516
--
1517

    
1518
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1519
    LANGUAGE sql
1520
    AS $_$
1521
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1522
$_$;
1523

    
1524

    
1525
--
1526
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1527
--
1528

    
1529
CREATE FUNCTION explain2str(sql text) RETURNS text
1530
    LANGUAGE sql
1531
    AS $_$
1532
SELECT util.join_strs(explain, $$
1533
$$) FROM util.explain($1)
1534
$_$;
1535

    
1536

    
1537
SET default_tablespace = '';
1538

    
1539
SET default_with_oids = false;
1540

    
1541
--
1542
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1543
--
1544

    
1545
CREATE TABLE explain (
1546
    line text NOT NULL
1547
);
1548

    
1549

    
1550
--
1551
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1552
--
1553

    
1554
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1555
    LANGUAGE sql
1556
    AS $_$
1557
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1558
$$||quote_nullable($1)||$$
1559
)$$)
1560
$_$;
1561

    
1562

    
1563
--
1564
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1565
--
1566

    
1567
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1568
usage:
1569
PERFORM util.explain2table($$
1570
query
1571
$$);
1572
';
1573

    
1574

    
1575
--
1576
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1577
--
1578

    
1579
CREATE FUNCTION first_word(str text) RETURNS text
1580
    LANGUAGE sql IMMUTABLE
1581
    AS $_$
1582
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1583
$_$;
1584

    
1585

    
1586
--
1587
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1588
--
1589

    
1590
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1591
    LANGUAGE sql IMMUTABLE
1592
    AS $_$
1593
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1594
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1595
) END
1596
$_$;
1597

    
1598

    
1599
--
1600
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1601
--
1602

    
1603
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1604
ensures that an array will always have proper non-NULL dimensions
1605
';
1606

    
1607

    
1608
--
1609
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1610
--
1611

    
1612
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1613
    LANGUAGE plpgsql
1614
    AS $_$
1615
DECLARE
1616
	PG_EXCEPTION_DETAIL text;
1617
	recreate_users_cmd text = util.save_drop_views(users);
1618
BEGIN
1619
	PERFORM util.eval(cmd);
1620
	PERFORM util.eval(recreate_users_cmd);
1621
EXCEPTION
1622
WHEN dependent_objects_still_exist THEN
1623
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1624
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1625
	users = array(SELECT * FROM util.regexp_matches_group(
1626
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1627
	IF util.is_empty(users) THEN RAISE; END IF;
1628
	PERFORM util.force_recreate(cmd, users);
1629
END;
1630
$_$;
1631

    
1632

    
1633
--
1634
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1635
--
1636

    
1637
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1638
idempotent
1639

    
1640
users: not necessary to provide this because it will be autopopulated
1641
';
1642

    
1643

    
1644
--
1645
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1646
--
1647

    
1648
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1649
    LANGUAGE plpgsql STRICT
1650
    AS $_$
1651
DECLARE
1652
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1653
$$||query;
1654
BEGIN
1655
	EXECUTE mk_view;
1656
EXCEPTION
1657
WHEN invalid_table_definition THEN
1658
	IF SQLERRM = 'cannot drop columns from view'
1659
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1660
	THEN
1661
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1662
		EXECUTE mk_view;
1663
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1664
	END IF;
1665
END;
1666
$_$;
1667

    
1668

    
1669
--
1670
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1671
--
1672

    
1673
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1674
idempotent
1675
';
1676

    
1677

    
1678
--
1679
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1680
--
1681

    
1682
CREATE FUNCTION grants_users() RETURNS SETOF text
1683
    LANGUAGE sql IMMUTABLE
1684
    AS $$
1685
VALUES ('bien_read'), ('public_')
1686
$$;
1687

    
1688

    
1689
--
1690
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1691
--
1692

    
1693
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1694
    LANGUAGE sql IMMUTABLE
1695
    AS $_$
1696
SELECT substring($2 for length($1)) = $1
1697
$_$;
1698

    
1699

    
1700
--
1701
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1702
--
1703

    
1704
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1705
    LANGUAGE sql STABLE
1706
    AS $_$
1707
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1708
$_$;
1709

    
1710

    
1711
--
1712
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1713
--
1714

    
1715
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1716
    LANGUAGE sql IMMUTABLE
1717
    AS $_$
1718
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1719
$_$;
1720

    
1721

    
1722
--
1723
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1724
--
1725

    
1726
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1727
avoids repeating the same value for each key
1728
';
1729

    
1730

    
1731
--
1732
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1733
--
1734

    
1735
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1736
    LANGUAGE sql IMMUTABLE
1737
    AS $_$
1738
SELECT COALESCE($1, $2)
1739
$_$;
1740

    
1741

    
1742
--
1743
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1744
--
1745

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

    
1750

    
1751
--
1752
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1753
--
1754

    
1755
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1756
    LANGUAGE sql
1757
    AS $_$
1758
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1759
$_$;
1760

    
1761

    
1762
--
1763
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1764
--
1765

    
1766
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1767
    LANGUAGE sql STABLE
1768
    AS $_$
1769
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1770
$_$;
1771

    
1772

    
1773
--
1774
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1775
--
1776

    
1777
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1778
    LANGUAGE sql IMMUTABLE
1779
    AS $_$
1780
SELECT util.array_length($1) = 0
1781
$_$;
1782

    
1783

    
1784
--
1785
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1786
--
1787

    
1788
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1789
    LANGUAGE sql IMMUTABLE
1790
    AS $_$
1791
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1792
$_$;
1793

    
1794

    
1795
--
1796
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1797
--
1798

    
1799
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1800
    LANGUAGE sql IMMUTABLE
1801
    AS $_$
1802
SELECT upper(util.first_word($1)) = ANY(
1803
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1804
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1805
)
1806
$_$;
1807

    
1808

    
1809
--
1810
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1811
--
1812

    
1813
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1814
    LANGUAGE sql IMMUTABLE
1815
    AS $_$
1816
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1817
$_$;
1818

    
1819

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

    
1824
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1825
    LANGUAGE sql IMMUTABLE
1826
    AS $_$
1827
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1828
$_$;
1829

    
1830

    
1831
--
1832
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1833
--
1834

    
1835
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1836
    LANGUAGE sql IMMUTABLE
1837
    AS $_$
1838
SELECT upper(util.first_word($1)) = 'SET'
1839
$_$;
1840

    
1841

    
1842
--
1843
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1844
--
1845

    
1846
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1847
    LANGUAGE sql STABLE
1848
    AS $_$
1849
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1850
$_$;
1851

    
1852

    
1853
--
1854
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1855
--
1856

    
1857
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1858
    LANGUAGE sql STABLE
1859
    AS $_$
1860
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1861
$_$;
1862

    
1863

    
1864
--
1865
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1866
--
1867

    
1868
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1869
    LANGUAGE sql IMMUTABLE STRICT
1870
    AS $_$
1871
SELECT $1 || $3 || $2
1872
$_$;
1873

    
1874

    
1875
--
1876
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1877
--
1878

    
1879
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1880
must be declared STRICT to use the special handling of STRICT aggregating functions
1881
';
1882

    
1883

    
1884
--
1885
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1886
--
1887

    
1888
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1889
    LANGUAGE sql IMMUTABLE
1890
    AS $_$
1891
SELECT $1 -- compare on the entire value
1892
$_$;
1893

    
1894

    
1895
--
1896
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1897
--
1898

    
1899
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1900
    LANGUAGE sql IMMUTABLE
1901
    AS $_$
1902
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1903
$_$;
1904

    
1905

    
1906
--
1907
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1908
--
1909

    
1910
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1911
    LANGUAGE sql IMMUTABLE
1912
    AS $_$
1913
SELECT ltrim($1, $$
1914
$$)
1915
$_$;
1916

    
1917

    
1918
--
1919
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1920
--
1921

    
1922
CREATE FUNCTION map_filter_insert() RETURNS trigger
1923
    LANGUAGE plpgsql
1924
    AS $$
1925
BEGIN
1926
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1927
	RETURN new;
1928
END;
1929
$$;
1930

    
1931

    
1932
--
1933
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1934
--
1935

    
1936
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1937
    LANGUAGE plpgsql STABLE STRICT
1938
    AS $_$
1939
DECLARE
1940
    value text;
1941
BEGIN
1942
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1943
        INTO value USING key;
1944
    RETURN value;
1945
END;
1946
$_$;
1947

    
1948

    
1949
--
1950
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1951
--
1952

    
1953
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1954
    LANGUAGE sql IMMUTABLE
1955
    AS $_$
1956
SELECT util._map(util.nulls_map($1), $2)
1957
$_$;
1958

    
1959

    
1960
--
1961
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1962
--
1963

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

    
1967
[1] inlining of function calls, which is different from constant folding
1968
[2] _map()''s profiling query
1969
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1970
and map_nulls()''s profiling query
1971
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
1972
both take ~920 ms.
1973
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.
1974
';
1975

    
1976

    
1977
--
1978
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
1979
--
1980

    
1981
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
1982
    LANGUAGE plpgsql STABLE STRICT
1983
    AS $_$
1984
BEGIN
1985
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
1986
END;
1987
$_$;
1988

    
1989

    
1990
--
1991
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
1992
--
1993

    
1994
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
1995
    LANGUAGE sql
1996
    AS $_$
1997
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
1998
$$||util.ltrim_nl($2));
1999
-- make sure the created table has the correct estimated row count
2000
SELECT util.analyze_($1);
2001

    
2002
SELECT util.append_comment($1, '
2003
contents generated from:
2004
'||util.ltrim_nl($2)||';
2005
');
2006
$_$;
2007

    
2008

    
2009
--
2010
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2011
--
2012

    
2013
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2014
idempotent
2015
';
2016

    
2017

    
2018
--
2019
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2020
--
2021

    
2022
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2023
    LANGUAGE sql
2024
    AS $_$
2025
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2026
$_$;
2027

    
2028

    
2029
--
2030
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2031
--
2032

    
2033
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2034
idempotent
2035
';
2036

    
2037

    
2038
--
2039
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2040
--
2041

    
2042
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2043
    LANGUAGE sql
2044
    AS $_$
2045
SELECT util.create_if_not_exists($$
2046
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2047
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2048
||quote_literal($2)||$$;
2049
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2050
constant
2051
';
2052
$$)
2053
$_$;
2054

    
2055

    
2056
--
2057
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2058
--
2059

    
2060
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2061
idempotent
2062
';
2063

    
2064

    
2065
--
2066
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2067
--
2068

    
2069
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2070
    LANGUAGE plpgsql STRICT
2071
    AS $_$
2072
DECLARE
2073
    type regtype = util.typeof(expr, col.table_::text::regtype);
2074
    col_name_sql text = quote_ident(col.name);
2075
BEGIN
2076
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2077
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2078
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2079
$$||expr||$$;
2080
$$);
2081
END;
2082
$_$;
2083

    
2084

    
2085
--
2086
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2087
--
2088

    
2089
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2090
idempotent
2091
';
2092

    
2093

    
2094
--
2095
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2096
--
2097

    
2098
CREATE FUNCTION mk_diff_query(left_ text, right_ text, cols text DEFAULT 'left_, right_'::text, join_cond text DEFAULT 'left_ %== right_ -- refer to EXPLAIN output for expansion of %=='::text, filter text DEFAULT 'left_ IS DISTINCT FROM right_'::text) RETURNS text
2099
    LANGUAGE sql IMMUTABLE
2100
    AS $_$
2101
SELECT
2102
$$SELECT
2103
$$||$3||$$
2104
FROM      $$||$1||$$ left_
2105
FULL JOIN $$||$2||$$ right_
2106
ON $$||$4||$$
2107
WHERE $$||$5||$$
2108
ORDER BY left_, right_
2109
$$
2110
$_$;
2111

    
2112

    
2113
--
2114
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2115
--
2116

    
2117
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2118
    LANGUAGE sql
2119
    AS $_$
2120
-- keys()
2121
SELECT util.mk_keys_func($1, ARRAY(
2122
SELECT col FROM util.typed_cols($1) col
2123
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2124
));
2125

    
2126
-- values_()
2127
SELECT util.mk_keys_func($1, COALESCE(
2128
	NULLIF(ARRAY(
2129
	SELECT col FROM util.typed_cols($1) col
2130
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2131
	), ARRAY[]::util.col_cast[])
2132
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2133
, 'values_');
2134
$_$;
2135

    
2136

    
2137
--
2138
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2139
--
2140

    
2141
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2142
    LANGUAGE sql
2143
    AS $_$
2144
SELECT util.create_if_not_exists($$
2145
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2146
($$||util.mk_typed_cols_list($2)||$$);
2147
$$);
2148

    
2149
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2150
$_$;
2151

    
2152

    
2153
--
2154
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2155
--
2156

    
2157
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2158
    LANGUAGE sql
2159
    AS $_$
2160
SELECT util.create_if_not_exists($$
2161
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2162
||util.qual_name($1)||$$)
2163
  RETURNS $$||util.qual_name($2)||$$ AS
2164
$BODY1$
2165
SELECT ROW($$||
2166
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2167
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2168
$BODY1$
2169
  LANGUAGE sql IMMUTABLE
2170
  COST 100;
2171
$$);
2172
$_$;
2173

    
2174

    
2175
--
2176
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2177
--
2178

    
2179
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2180
    LANGUAGE sql
2181
    AS $_$
2182
SELECT util.create_if_not_exists($$
2183
CREATE TABLE $$||$1||$$
2184
(
2185
    LIKE util.map INCLUDING ALL
2186
);
2187

    
2188
CREATE TRIGGER map_filter_insert
2189
  BEFORE INSERT
2190
  ON $$||$1||$$
2191
  FOR EACH ROW
2192
  EXECUTE PROCEDURE util.map_filter_insert();
2193
$$)
2194
$_$;
2195

    
2196

    
2197
--
2198
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2199
--
2200

    
2201
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2202
    LANGUAGE sql IMMUTABLE
2203
    AS $_$
2204
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2205
util.qual_name((unnest).type), ''), '')
2206
FROM unnest($1)
2207
$_$;
2208

    
2209

    
2210
--
2211
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2212
--
2213

    
2214
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2215
    LANGUAGE sql IMMUTABLE
2216
    AS $_$
2217
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2218
$_$;
2219

    
2220

    
2221
--
2222
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2223
--
2224

    
2225
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2226
auto-appends util to the search_path to enable use of util operators
2227
';
2228

    
2229

    
2230
--
2231
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2232
--
2233

    
2234
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2235
    LANGUAGE sql IMMUTABLE
2236
    AS $_$
2237
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2238
$_$;
2239

    
2240

    
2241
--
2242
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2243
--
2244

    
2245
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2246
    LANGUAGE sql IMMUTABLE
2247
    AS $_$
2248
/* debug_print_return_value() needed because this function is used with EXECUTE
2249
rather than util.eval() (in order to affect the calling function), so the
2250
search_path would not otherwise be printed */
2251
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2252
||$$ search_path TO $$||$1
2253
$_$;
2254

    
2255

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

    
2260
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2261
    LANGUAGE sql
2262
    AS $_$
2263
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2264
$_$;
2265

    
2266

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

    
2271
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2272
idempotent
2273
';
2274

    
2275

    
2276
--
2277
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2278
--
2279

    
2280
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2281
    LANGUAGE plpgsql STRICT
2282
    AS $_$
2283
DECLARE
2284
	view_qual_name text = util.qual_name(view_);
2285
BEGIN
2286
	EXECUTE $$
2287
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2288
  RETURNS SETOF $$||view_||$$ AS
2289
$BODY1$
2290
SELECT * FROM $$||view_qual_name||$$
2291
ORDER BY sort_col
2292
LIMIT $1 OFFSET $2
2293
$BODY1$
2294
  LANGUAGE sql STABLE
2295
  COST 100
2296
  ROWS 1000
2297
$$;
2298
	
2299
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2300
END;
2301
$_$;
2302

    
2303

    
2304
--
2305
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2306
--
2307

    
2308
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2309
    LANGUAGE plpgsql STRICT
2310
    AS $_$
2311
DECLARE
2312
	view_qual_name text = util.qual_name(view_);
2313
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2314
BEGIN
2315
	EXECUTE $$
2316
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2317
  RETURNS integer AS
2318
$BODY1$
2319
SELECT $$||quote_ident(row_num_col)||$$
2320
FROM $$||view_qual_name||$$
2321
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2322
LIMIT 1
2323
$BODY1$
2324
  LANGUAGE sql STABLE
2325
  COST 100;
2326
$$;
2327
	
2328
	EXECUTE $$
2329
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2330
  RETURNS SETOF $$||view_||$$ AS
2331
$BODY1$
2332
SELECT * FROM $$||view_qual_name||$$
2333
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2334
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2335
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2336
ORDER BY $$||quote_ident(row_num_col)||$$
2337
$BODY1$
2338
  LANGUAGE sql STABLE
2339
  COST 100
2340
  ROWS 1000
2341
$$;
2342
	
2343
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2344
END;
2345
$_$;
2346

    
2347

    
2348
--
2349
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2350
--
2351

    
2352
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2353
    LANGUAGE plpgsql STRICT
2354
    AS $_$
2355
DECLARE
2356
	view_qual_name text = util.qual_name(view_);
2357
BEGIN
2358
	EXECUTE $$
2359
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2360
  RETURNS SETOF $$||view_||$$
2361
  SET enable_sort TO 'off'
2362
  AS
2363
$BODY1$
2364
SELECT * FROM $$||view_qual_name||$$($2, $3)
2365
$BODY1$
2366
  LANGUAGE sql STABLE
2367
  COST 100
2368
  ROWS 1000
2369
;
2370
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2371
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2372
If you want to run EXPLAIN and get expanded output, use the regular subset
2373
function instead. (When a config param is set on a function, EXPLAIN produces
2374
just a function scan.)
2375
';
2376
$$;
2377
END;
2378
$_$;
2379

    
2380

    
2381
--
2382
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2383
--
2384

    
2385
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2386
creates subset function which turns off enable_sort
2387
';
2388

    
2389

    
2390
--
2391
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2392
--
2393

    
2394
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2395
    LANGUAGE sql IMMUTABLE
2396
    AS $_$
2397
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2398
util.qual_name((unnest).type), ', '), '')
2399
FROM unnest($1)
2400
$_$;
2401

    
2402

    
2403
--
2404
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2405
--
2406

    
2407
CREATE FUNCTION name(table_ regclass) RETURNS text
2408
    LANGUAGE sql STABLE
2409
    AS $_$
2410
SELECT relname::text FROM pg_class WHERE oid = $1
2411
$_$;
2412

    
2413

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

    
2418
CREATE FUNCTION name(type regtype) RETURNS text
2419
    LANGUAGE sql STABLE
2420
    AS $_$
2421
SELECT typname::text FROM pg_type WHERE oid = $1
2422
$_$;
2423

    
2424

    
2425
--
2426
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2427
--
2428

    
2429
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2430
    LANGUAGE sql IMMUTABLE
2431
    AS $_$
2432
SELECT octet_length($1) >= util.namedatalen() - $2
2433
$_$;
2434

    
2435

    
2436
--
2437
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2438
--
2439

    
2440
CREATE FUNCTION namedatalen() RETURNS integer
2441
    LANGUAGE sql IMMUTABLE
2442
    AS $$
2443
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2444
$$;
2445

    
2446

    
2447
--
2448
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2449
--
2450

    
2451
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2452
    LANGUAGE sql IMMUTABLE
2453
    AS $_$
2454
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2455
$_$;
2456

    
2457

    
2458
--
2459
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2460
--
2461

    
2462
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2463
    LANGUAGE sql IMMUTABLE
2464
    AS $_$
2465
SELECT $1 IS NOT NULL
2466
$_$;
2467

    
2468

    
2469
--
2470
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2471
--
2472

    
2473
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2474
    LANGUAGE sql IMMUTABLE
2475
    AS $_$
2476
SELECT util.hstore($1, NULL) || '*=>*'
2477
$_$;
2478

    
2479

    
2480
--
2481
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2482
--
2483

    
2484
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2485
for use with _map()
2486
';
2487

    
2488

    
2489
--
2490
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2491
--
2492

    
2493
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2494
    LANGUAGE sql IMMUTABLE
2495
    AS $_$
2496
SELECT $2 + COALESCE($1, 0)
2497
$_$;
2498

    
2499

    
2500
--
2501
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2502
--
2503

    
2504
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2505
    LANGUAGE sql
2506
    AS $_$
2507
SELECT util.eval($$INSERT INTO $$||$1||$$
2508
$$||util.ltrim_nl($2));
2509
-- make sure the created table has the correct estimated row count
2510
SELECT util.analyze_($1);
2511
$_$;
2512

    
2513

    
2514
--
2515
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2516
--
2517

    
2518
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2519
    LANGUAGE sql IMMUTABLE
2520
    AS $_$
2521
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2522
$_$;
2523

    
2524

    
2525
--
2526
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2527
--
2528

    
2529
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2530
    LANGUAGE sql
2531
    AS $_$
2532
SELECT util.set_comment($1, concat($2, util.comment($1)))
2533
$_$;
2534

    
2535

    
2536
--
2537
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2538
--
2539

    
2540
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2541
comment: must start and end with a newline
2542
';
2543

    
2544

    
2545
--
2546
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2547
--
2548

    
2549
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2550
    LANGUAGE sql IMMUTABLE
2551
    AS $_$
2552
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2553
$_$;
2554

    
2555

    
2556
--
2557
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2558
--
2559

    
2560
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2561
    LANGUAGE sql STABLE
2562
    SET search_path TO pg_temp
2563
    AS $_$
2564
SELECT $1::text
2565
$_$;
2566

    
2567

    
2568
--
2569
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2570
--
2571

    
2572
CREATE FUNCTION qual_name(type regtype) RETURNS text
2573
    LANGUAGE sql STABLE
2574
    SET search_path TO pg_temp
2575
    AS $_$
2576
SELECT $1::text
2577
$_$;
2578

    
2579

    
2580
--
2581
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2582
--
2583

    
2584
COMMENT ON FUNCTION qual_name(type regtype) IS '
2585
a type''s schema-qualified name
2586
';
2587

    
2588

    
2589
--
2590
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2591
--
2592

    
2593
CREATE FUNCTION qual_name(type unknown) RETURNS text
2594
    LANGUAGE sql STABLE
2595
    AS $_$
2596
SELECT util.qual_name($1::text::regtype)
2597
$_$;
2598

    
2599

    
2600
--
2601
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2602
--
2603

    
2604
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2605
    LANGUAGE sql IMMUTABLE
2606
    AS $_$
2607
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2608
$_$;
2609

    
2610

    
2611
--
2612
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2613
--
2614

    
2615
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2616
    LANGUAGE sql IMMUTABLE
2617
    AS $_$
2618
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2619
$_$;
2620

    
2621

    
2622
--
2623
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2624
--
2625

    
2626
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2627
    LANGUAGE sql IMMUTABLE
2628
    AS $_$
2629
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2630
$_$;
2631

    
2632

    
2633
--
2634
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2635
--
2636

    
2637
CREATE FUNCTION raise(type text, msg text) RETURNS void
2638
    LANGUAGE sql IMMUTABLE
2639
    AS $_X$
2640
SELECT util.eval($$
2641
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2642
  RETURNS void AS
2643
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2644
$__BODY1$
2645
BEGIN
2646
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2647
END;
2648
$__BODY1$
2649
  LANGUAGE plpgsql IMMUTABLE
2650
  COST 100;
2651
$$, verbose_ := false);
2652

    
2653
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2654
$_X$;
2655

    
2656

    
2657
--
2658
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2659
--
2660

    
2661
COMMENT ON FUNCTION raise(type text, msg text) IS '
2662
type: a log level from
2663
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2664
or a condition name from
2665
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2666
';
2667

    
2668

    
2669
--
2670
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2671
--
2672

    
2673
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2674
    LANGUAGE sql IMMUTABLE
2675
    AS $_$
2676
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2677
$_$;
2678

    
2679

    
2680
--
2681
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2682
--
2683

    
2684
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2685
    LANGUAGE plpgsql IMMUTABLE STRICT
2686
    AS $$
2687
BEGIN
2688
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2689
END;
2690
$$;
2691

    
2692

    
2693
--
2694
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2695
--
2696

    
2697
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2698
    LANGUAGE sql IMMUTABLE
2699
    AS $_$
2700
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2701
$_$;
2702

    
2703

    
2704
--
2705
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2706
--
2707

    
2708
CREATE FUNCTION regexp_quote(str text) RETURNS text
2709
    LANGUAGE sql IMMUTABLE
2710
    AS $_$
2711
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2712
$_$;
2713

    
2714

    
2715
--
2716
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2717
--
2718

    
2719
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2720
    LANGUAGE sql IMMUTABLE
2721
    AS $_$
2722
SELECT (CASE WHEN right($1, 1) = ')'
2723
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2724
$_$;
2725

    
2726

    
2727
--
2728
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2729
--
2730

    
2731
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2732
    LANGUAGE sql STABLE
2733
    AS $_$
2734
SELECT util.relation_type(util.relation_type_char($1))
2735
$_$;
2736

    
2737

    
2738
--
2739
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2740
--
2741

    
2742
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2743
    LANGUAGE sql IMMUTABLE
2744
    AS $_$
2745
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2746
$_$;
2747

    
2748

    
2749
--
2750
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2751
--
2752

    
2753
CREATE FUNCTION relation_type(type regtype) RETURNS text
2754
    LANGUAGE sql IMMUTABLE
2755
    AS $$
2756
SELECT 'TYPE'::text
2757
$$;
2758

    
2759

    
2760
--
2761
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2762
--
2763

    
2764
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2765
    LANGUAGE sql STABLE
2766
    AS $_$
2767
SELECT relkind FROM pg_class WHERE oid = $1
2768
$_$;
2769

    
2770

    
2771
--
2772
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2773
--
2774

    
2775
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2776
    LANGUAGE sql
2777
    AS $_$
2778
/* can't have in_table/out_table inherit from *each other*, because inheritance
2779
also causes the rows of the parent table to be included in the child table.
2780
instead, they need to inherit from a common, empty table. */
2781
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2782
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2783
SELECT util.inherit($2, $4);
2784
SELECT util.inherit($3, $4);
2785

    
2786
SELECT util.rematerialize_query($1, $$
2787
SELECT * FROM util.diff(
2788
  $$||util.quote_typed($2)||$$
2789
, $$||util.quote_typed($3)||$$
2790
, NULL::$$||$4||$$)
2791
$$);
2792

    
2793
/* the table unfortunately cannot be *materialized* in human-readable form,
2794
because this would create column name collisions between the two sides */
2795
SELECT util.prepend_comment($1, '
2796
to view this table in human-readable form (with each side''s tuple column
2797
expanded to its component fields):
2798
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2799
');
2800
$_$;
2801

    
2802

    
2803
--
2804
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2805
--
2806

    
2807
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2808
type_table (*required*): table to create as the shared base type
2809
';
2810

    
2811

    
2812
--
2813
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2814
--
2815

    
2816
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2817
    LANGUAGE sql
2818
    AS $_$
2819
SELECT util.drop_table($1);
2820
SELECT util.materialize_query($1, $2);
2821
$_$;
2822

    
2823

    
2824
--
2825
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2826
--
2827

    
2828
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2829
idempotent, but repeats action each time
2830
';
2831

    
2832

    
2833
--
2834
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2835
--
2836

    
2837
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2838
    LANGUAGE sql
2839
    AS $_$
2840
SELECT util.drop_table($1);
2841
SELECT util.materialize_view($1, $2);
2842
$_$;
2843

    
2844

    
2845
--
2846
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2847
--
2848

    
2849
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2850
idempotent, but repeats action each time
2851
';
2852

    
2853

    
2854
--
2855
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2856
--
2857

    
2858
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2859
    LANGUAGE sql
2860
    AS $_$
2861
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2862
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2863
FROM util.col_names($1::text::regtype) f (name);
2864
SELECT NULL::void; -- don't fold away functions called in previous query
2865
$_$;
2866

    
2867

    
2868
--
2869
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2870
--
2871

    
2872
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2873
idempotent
2874
';
2875

    
2876

    
2877
--
2878
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2879
--
2880

    
2881
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2882
    LANGUAGE sql
2883
    AS $_$
2884
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2885
included in the debug SQL */
2886
SELECT util.rename_relation(util.qual_name($1), $2)
2887
$_$;
2888

    
2889

    
2890
--
2891
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2892
--
2893

    
2894
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2895
    LANGUAGE sql
2896
    AS $_$
2897
/* 'ALTER TABLE can be used with views too'
2898
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2899
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2900
||quote_ident($2))
2901
$_$;
2902

    
2903

    
2904
--
2905
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2906
--
2907

    
2908
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2909
idempotent
2910
';
2911

    
2912

    
2913
--
2914
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2915
--
2916

    
2917
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2918
    LANGUAGE sql IMMUTABLE
2919
    AS $_$
2920
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2921
$_$;
2922

    
2923

    
2924
--
2925
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2926
--
2927

    
2928
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2929
max_prefix_len: when str may have been truncated (eg. as a table name) due to the prepending of a prefix, support prefixes up to this length 
2930
';
2931

    
2932

    
2933
--
2934
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2935
--
2936

    
2937
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2938
    LANGUAGE sql
2939
    AS $_$
2940
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2941
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2942
SELECT util.set_col_names($1, $2);
2943
$_$;
2944

    
2945

    
2946
--
2947
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2948
--
2949

    
2950
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2951
idempotent.
2952
alters the names table, so it will need to be repopulated after running this function.
2953
';
2954

    
2955

    
2956
--
2957
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2958
--
2959

    
2960
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2961
    LANGUAGE sql
2962
    AS $_$
2963
SELECT util.drop_table($1);
2964
SELECT util.mk_map_table($1);
2965
$_$;
2966

    
2967

    
2968
--
2969
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2970
--
2971

    
2972
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
2973
    LANGUAGE sql IMMUTABLE
2974
    AS $_$
2975
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
2976
$_$;
2977

    
2978

    
2979
--
2980
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
2981
--
2982

    
2983
CREATE FUNCTION runnable_sql(sql text) RETURNS text
2984
    LANGUAGE sql IMMUTABLE
2985
    AS $_$
2986
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
2987
ELSE util.mk_set_search_path(for_printing := true)||$$;
2988
$$ END)||$1
2989
$_$;
2990

    
2991

    
2992
--
2993
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
2994
--
2995

    
2996
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
2997
    LANGUAGE plpgsql STRICT
2998
    AS $_$
2999
DECLARE
3000
	result text = NULL;
3001
BEGIN
3002
	BEGIN
3003
		result = util.show_create_view(view_);
3004
		PERFORM util.eval($$DROP VIEW $$||view_);
3005
	EXCEPTION
3006
		WHEN undefined_table THEN NULL;
3007
	END;
3008
	RETURN result;
3009
END;
3010
$_$;
3011

    
3012

    
3013
--
3014
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3015
--
3016

    
3017
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3018
    LANGUAGE sql
3019
    AS $_$
3020
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3021
$_$;
3022

    
3023

    
3024
--
3025
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3026
--
3027

    
3028
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3029
    LANGUAGE sql STABLE
3030
    AS $_$
3031
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3032
$_$;
3033

    
3034

    
3035
--
3036
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3037
--
3038

    
3039
CREATE FUNCTION schema(table_ regclass) RETURNS text
3040
    LANGUAGE sql STABLE
3041
    AS $_$
3042
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3043
$_$;
3044

    
3045

    
3046
--
3047
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3048
--
3049

    
3050
CREATE FUNCTION schema(type regtype) RETURNS text
3051
    LANGUAGE sql STABLE
3052
    AS $_$
3053
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3054
$_$;
3055

    
3056

    
3057
--
3058
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3059
--
3060

    
3061
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3062
    LANGUAGE sql STABLE
3063
    AS $_$
3064
SELECT util.schema(pg_typeof($1))
3065
$_$;
3066

    
3067

    
3068
--
3069
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3070
--
3071

    
3072
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3073
    LANGUAGE sql STABLE
3074
    AS $_$
3075
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3076
$_$;
3077

    
3078

    
3079
--
3080
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3081
--
3082

    
3083
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3084
a schema bundle is a group of schemas with a common prefix
3085
';
3086

    
3087

    
3088
--
3089
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3090
--
3091

    
3092
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3093
    LANGUAGE sql
3094
    AS $_$
3095
SELECT util.schema_rename(old_schema,
3096
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3097
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3098
SELECT NULL::void; -- don't fold away functions called in previous query
3099
$_$;
3100

    
3101

    
3102
--
3103
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3104
--
3105

    
3106
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3107
    LANGUAGE plpgsql
3108
    AS $$
3109
BEGIN
3110
	-- don't schema_bundle_rm() the schema_bundle to keep!
3111
	IF replace = with_ THEN RETURN; END IF;
3112
	
3113
	PERFORM util.schema_bundle_rm(replace);
3114
	PERFORM util.schema_bundle_rename(with_, replace);
3115
END;
3116
$$;
3117

    
3118

    
3119
--
3120
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3121
--
3122

    
3123
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3124
    LANGUAGE sql
3125
    AS $_$
3126
SELECT util.schema_rm(schema)
3127
FROM util.schema_bundle_get_schemas($1) f (schema);
3128
SELECT NULL::void; -- don't fold away functions called in previous query
3129
$_$;
3130

    
3131

    
3132
--
3133
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3134
--
3135

    
3136
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3137
    LANGUAGE sql STABLE
3138
    AS $_$
3139
SELECT quote_ident(util.schema($1))
3140
$_$;
3141

    
3142

    
3143
--
3144
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3145
--
3146

    
3147
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3148
    LANGUAGE sql IMMUTABLE
3149
    AS $_$
3150
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3151
$_$;
3152

    
3153

    
3154
--
3155
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3156
--
3157

    
3158
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3159
    LANGUAGE sql STABLE
3160
    AS $_$
3161
SELECT oid FROM pg_namespace WHERE nspname = $1
3162
$_$;
3163

    
3164

    
3165
--
3166
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3167
--
3168

    
3169
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3170
    LANGUAGE sql IMMUTABLE
3171
    AS $_$
3172
SELECT util.schema_regexp(schema_anchor := $1)
3173
$_$;
3174

    
3175

    
3176
--
3177
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3178
--
3179

    
3180
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3181
    LANGUAGE sql IMMUTABLE
3182
    AS $_$
3183
SELECT util.str_equality_regexp(util.schema($1))
3184
$_$;
3185

    
3186

    
3187
--
3188
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3189
--
3190

    
3191
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3192
    LANGUAGE sql
3193
    AS $_$
3194
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3195
$_$;
3196

    
3197

    
3198
--
3199
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3200
--
3201

    
3202
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3203
    LANGUAGE plpgsql
3204
    AS $$
3205
BEGIN
3206
	-- don't schema_rm() the schema to keep!
3207
	IF replace = with_ THEN RETURN; END IF;
3208
	
3209
	PERFORM util.schema_rm(replace);
3210
	PERFORM util.schema_rename(with_, replace);
3211
END;
3212
$$;
3213

    
3214

    
3215
--
3216
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3217
--
3218

    
3219
CREATE FUNCTION schema_rm(schema text) RETURNS void
3220
    LANGUAGE sql
3221
    AS $_$
3222
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3223
$_$;
3224

    
3225

    
3226
--
3227
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3228
--
3229

    
3230
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3231
    LANGUAGE sql
3232
    AS $_$
3233
SELECT util.eval(
3234
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3235
$_$;
3236

    
3237

    
3238
--
3239
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3240
--
3241

    
3242
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3243
    LANGUAGE plpgsql STRICT
3244
    AS $_$
3245
DECLARE
3246
    old text[] = ARRAY(SELECT util.col_names(table_));
3247
    new text[] = ARRAY(SELECT util.map_values(names));
3248
BEGIN
3249
    old = old[1:array_length(new, 1)]; -- truncate to same length
3250
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3251
||$$ TO $$||quote_ident(value))
3252
    FROM each(hstore(old, new))
3253
    WHERE value != key -- not same name
3254
    ;
3255
END;
3256
$_$;
3257

    
3258

    
3259
--
3260
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3261
--
3262

    
3263
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3264
idempotent
3265
';
3266

    
3267

    
3268
--
3269
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3270
--
3271

    
3272
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3273
    LANGUAGE plpgsql STRICT
3274
    AS $_$
3275
DECLARE
3276
	row_ util.map;
3277
BEGIN
3278
	-- rename any metadata cols rather than re-adding them with new names
3279
	BEGIN
3280
		PERFORM util.set_col_names(table_, names);
3281
	EXCEPTION
3282
		WHEN array_subscript_error THEN -- selective suppress
3283
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3284
				-- metadata cols not yet added
3285
			ELSE RAISE;
3286
			END IF;
3287
	END;
3288
	
3289
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3290
	LOOP
3291
		PERFORM util.mk_const_col((table_, row_."to"),
3292
			substring(row_."from" from 2));
3293
	END LOOP;
3294
	
3295
	PERFORM util.set_col_names(table_, names);
3296
END;
3297
$_$;
3298

    
3299

    
3300
--
3301
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3302
--
3303

    
3304
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3305
idempotent.
3306
the metadata mappings must be *last* in the names table.
3307
';
3308

    
3309

    
3310
--
3311
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3312
--
3313

    
3314
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3315
    LANGUAGE plpgsql STRICT
3316
    AS $_$
3317
DECLARE
3318
    sql text = $$ALTER TABLE $$||table_||$$
3319
$$||NULLIF(array_to_string(ARRAY(
3320
    SELECT
3321
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3322
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3323
    FROM
3324
    (
3325
        SELECT
3326
          quote_ident(col_name) AS col_name_sql
3327
        , util.col_type((table_, col_name)) AS curr_type
3328
        , type AS target_type
3329
        FROM unnest(col_casts)
3330
    ) s
3331
    WHERE curr_type != target_type
3332
), '
3333
, '), '');
3334
BEGIN
3335
    PERFORM util.debug_print_sql(sql);
3336
    EXECUTE COALESCE(sql, '');
3337
END;
3338
$_$;
3339

    
3340

    
3341
--
3342
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3343
--
3344

    
3345
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3346
idempotent
3347
';
3348

    
3349

    
3350
--
3351
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3352
--
3353

    
3354
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3355
    LANGUAGE sql
3356
    AS $_$
3357
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3358
$_$;
3359

    
3360

    
3361
--
3362
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3363
--
3364

    
3365
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3366
    LANGUAGE sql
3367
    AS $_$
3368
SELECT util.eval(util.mk_set_search_path($1, $2))
3369
$_$;
3370

    
3371

    
3372
--
3373
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3374
--
3375

    
3376
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3377
    LANGUAGE sql STABLE
3378
    AS $_$
3379
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3380
$$||util.show_grants_for($1)
3381
$_$;
3382

    
3383

    
3384
--
3385
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3386
--
3387

    
3388
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3389
    LANGUAGE sql STABLE
3390
    AS $_$
3391
SELECT string_agg(cmd, '')
3392
FROM
3393
(
3394
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3395
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3396
$$ ELSE '' END) AS cmd
3397
	FROM util.grants_users() f (user_)
3398
) s
3399
$_$;
3400

    
3401

    
3402
--
3403
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3404
--
3405

    
3406
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3407
    LANGUAGE sql STABLE
3408
    AS $_$
3409
SELECT oid FROM pg_class
3410
WHERE relkind = ANY($3) AND relname ~ $1
3411
AND util.schema_matches(util.schema(relnamespace), $2)
3412
ORDER BY relname
3413
$_$;
3414

    
3415

    
3416
--
3417
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3418
--
3419

    
3420
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3421
    LANGUAGE sql STABLE
3422
    AS $_$
3423
SELECT oid
3424
FROM pg_type
3425
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3426
ORDER BY typname
3427
$_$;
3428

    
3429

    
3430
--
3431
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3432
--
3433

    
3434
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3435
    LANGUAGE sql STABLE
3436
    AS $_$
3437
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3438
$_$;
3439

    
3440

    
3441
--
3442
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3443
--
3444

    
3445
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3446
    LANGUAGE sql IMMUTABLE
3447
    AS $_$
3448
SELECT '^'||util.regexp_quote($1)||'$'
3449
$_$;
3450

    
3451

    
3452
--
3453
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3454
--
3455

    
3456
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3457
    LANGUAGE plpgsql STABLE STRICT
3458
    AS $_$
3459
DECLARE
3460
    hstore hstore;
3461
BEGIN
3462
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3463
        table_||$$))$$ INTO STRICT hstore;
3464
    RETURN hstore;
3465
END;
3466
$_$;
3467

    
3468

    
3469
--
3470
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3471
--
3472

    
3473
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3474
    LANGUAGE sql STABLE
3475
    AS $_$
3476
SELECT COUNT(*) > 0 FROM pg_constraint
3477
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3478
$_$;
3479

    
3480

    
3481
--
3482
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3483
--
3484

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

    
3489

    
3490
--
3491
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3492
--
3493

    
3494
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3495
    LANGUAGE sql
3496
    AS $_$
3497
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3498
||quote_ident($2)||$$ CHECK (true)$$)
3499
$_$;
3500

    
3501

    
3502
--
3503
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3504
--
3505

    
3506
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3507
stores a status flag by the presence of a table constraint.
3508
idempotent.
3509
';
3510

    
3511

    
3512
--
3513
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3514
--
3515

    
3516
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3517
    LANGUAGE sql STABLE
3518
    AS $_$
3519
SELECT util.table_flag__get($1, 'nulls_mapped')
3520
$_$;
3521

    
3522

    
3523
--
3524
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3525
--
3526

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

    
3531

    
3532
--
3533
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3534
--
3535

    
3536
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3537
    LANGUAGE sql
3538
    AS $_$
3539
SELECT util.table_flag__set($1, 'nulls_mapped')
3540
$_$;
3541

    
3542

    
3543
--
3544
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3545
--
3546

    
3547
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3548
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3549
idempotent.
3550
';
3551

    
3552

    
3553
--
3554
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3555
--
3556

    
3557
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3558
    LANGUAGE sql
3559
    AS $_$
3560
-- save data before truncating main table
3561
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3562

    
3563
-- repopulate main table w/ copies column
3564
SELECT util.truncate($1);
3565
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3566
SELECT util.populate_table($1, $$
3567
SELECT (table_).*, copies
3568
FROM (
3569
	SELECT table_, COUNT(*) AS copies
3570
	FROM pg_temp.__copy table_
3571
	GROUP BY table_
3572
) s
3573
$$);
3574

    
3575
-- delete temp table so it doesn't stay around until end of connection
3576
SELECT util.drop_table('pg_temp.__copy');
3577
$_$;
3578

    
3579

    
3580
--
3581
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3582
--
3583

    
3584
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3585
    LANGUAGE plpgsql STRICT
3586
    AS $_$
3587
DECLARE
3588
    row record;
3589
BEGIN
3590
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3591
    LOOP
3592
        IF row.global_name != row.name THEN
3593
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3594
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3595
        END IF;
3596
    END LOOP;
3597
END;
3598
$_$;
3599

    
3600

    
3601
--
3602
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3603
--
3604

    
3605
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3606
idempotent
3607
';
3608

    
3609

    
3610
--
3611
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3612
--
3613

    
3614
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3615
    LANGUAGE sql
3616
    AS $_$
3617
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3618
SELECT NULL::void; -- don't fold away functions called in previous query
3619
$_$;
3620

    
3621

    
3622
--
3623
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3624
--
3625

    
3626
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3627
trims table_ to include only columns in the original data.
3628
idempotent.
3629
';
3630

    
3631

    
3632
--
3633
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3634
--
3635

    
3636
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3637
    LANGUAGE plpgsql STRICT
3638
    AS $_$
3639
BEGIN
3640
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3641
END;
3642
$_$;
3643

    
3644

    
3645
--
3646
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3647
--
3648

    
3649
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3650
idempotent
3651
';
3652

    
3653

    
3654
--
3655
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3656
--
3657

    
3658
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3659
    LANGUAGE sql IMMUTABLE
3660
    AS $_$
3661
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3662
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3663
$_$;
3664

    
3665

    
3666
--
3667
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3668
--
3669

    
3670
CREATE FUNCTION try_create(sql text) RETURNS void
3671
    LANGUAGE plpgsql STRICT
3672
    AS $$
3673
BEGIN
3674
    PERFORM util.eval(sql);
3675
EXCEPTION
3676
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3677
    WHEN undefined_column THEN NULL;
3678
    WHEN duplicate_column THEN NULL;
3679
END;
3680
$$;
3681

    
3682

    
3683
--
3684
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3685
--
3686

    
3687
COMMENT ON FUNCTION try_create(sql text) IS '
3688
idempotent
3689
';
3690

    
3691

    
3692
--
3693
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3694
--
3695

    
3696
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3697
    LANGUAGE sql
3698
    AS $_$
3699
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3700
$_$;
3701

    
3702

    
3703
--
3704
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3705
--
3706

    
3707
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3708
idempotent
3709
';
3710

    
3711

    
3712
--
3713
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3714
--
3715

    
3716
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3717
    LANGUAGE sql IMMUTABLE
3718
    AS $_$
3719
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3720
$_$;
3721

    
3722

    
3723
--
3724
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3725
--
3726

    
3727
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3728
a type''s NOT NULL qualifier
3729
';
3730

    
3731

    
3732
--
3733
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3734
--
3735

    
3736
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3737
    LANGUAGE sql STABLE
3738
    AS $_$
3739
SELECT (attname::text, atttypid)::util.col_cast
3740
FROM pg_attribute
3741
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3742
ORDER BY attnum
3743
$_$;
3744

    
3745

    
3746
--
3747
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3748
--
3749

    
3750
CREATE FUNCTION typeof(value anyelement) RETURNS text
3751
    LANGUAGE sql IMMUTABLE
3752
    AS $_$
3753
SELECT util.qual_name(pg_typeof($1))
3754
$_$;
3755

    
3756

    
3757
--
3758
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3759
--
3760

    
3761
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3762
    LANGUAGE plpgsql STABLE
3763
    AS $_$
3764
DECLARE
3765
    type regtype;
3766
BEGIN
3767
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3768
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3769
    RETURN type;
3770
END;
3771
$_$;
3772

    
3773

    
3774
--
3775
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3776
--
3777

    
3778
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3779
    LANGUAGE sql
3780
    AS $_$
3781
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3782
$_$;
3783

    
3784

    
3785
--
3786
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3787
--
3788

    
3789
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3790
auto-appends util to the search_path to enable use of util operators
3791
';
3792

    
3793

    
3794
--
3795
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3796
--
3797

    
3798
CREATE AGGREGATE all_same(anyelement) (
3799
    SFUNC = all_same_transform,
3800
    STYPE = anyarray,
3801
    FINALFUNC = all_same_final
3802
);
3803

    
3804

    
3805
--
3806
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3807
--
3808

    
3809
COMMENT ON AGGREGATE all_same(anyelement) IS '
3810
includes NULLs in comparison
3811
';
3812

    
3813

    
3814
--
3815
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3816
--
3817

    
3818
CREATE AGGREGATE join_strs(text, text) (
3819
    SFUNC = join_strs_transform,
3820
    STYPE = text
3821
);
3822

    
3823

    
3824
--
3825
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3826
--
3827

    
3828
CREATE OPERATOR %== (
3829
    PROCEDURE = "%==",
3830
    LEFTARG = anyelement,
3831
    RIGHTARG = anyelement
3832
);
3833

    
3834

    
3835
--
3836
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3837
--
3838

    
3839
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3840
returns whether the map-keys of the compared values are the same
3841
(mnemonic: % is the Perl symbol for a hash map)
3842

    
3843
should be overridden for types that store both keys and values
3844

    
3845
used in a FULL JOIN to select which columns to join on
3846
';
3847

    
3848

    
3849
--
3850
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3851
--
3852

    
3853
CREATE OPERATOR -> (
3854
    PROCEDURE = map_get,
3855
    LEFTARG = regclass,
3856
    RIGHTARG = text
3857
);
3858

    
3859

    
3860
--
3861
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3862
--
3863

    
3864
CREATE OPERATOR => (
3865
    PROCEDURE = hstore,
3866
    LEFTARG = text[],
3867
    RIGHTARG = text
3868
);
3869

    
3870

    
3871
--
3872
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3873
--
3874

    
3875
COMMENT ON OPERATOR => (text[], text) IS '
3876
usage: array[''key1'', ...]::text[] => ''value''
3877
';
3878

    
3879

    
3880
--
3881
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3882
--
3883

    
3884
CREATE OPERATOR ?*>= (
3885
    PROCEDURE = is_populated_more_often_than,
3886
    LEFTARG = anyelement,
3887
    RIGHTARG = anyelement
3888
);
3889

    
3890

    
3891
--
3892
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3893
--
3894

    
3895
CREATE OPERATOR ?>= (
3896
    PROCEDURE = is_more_complete_than,
3897
    LEFTARG = anyelement,
3898
    RIGHTARG = anyelement
3899
);
3900

    
3901

    
3902
--
3903
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3904
--
3905

    
3906
CREATE OPERATOR ||% (
3907
    PROCEDURE = concat_esc,
3908
    LEFTARG = text,
3909
    RIGHTARG = text
3910
);
3911

    
3912

    
3913
--
3914
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3915
--
3916

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

    
3921

    
3922
--
3923
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3924
--
3925

    
3926
CREATE TABLE map (
3927
    "from" text NOT NULL,
3928
    "to" text,
3929
    filter text,
3930
    notes text
3931
);
3932

    
3933

    
3934
--
3935
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3936
--
3937

    
3938

    
3939

    
3940
--
3941
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3942
--
3943

    
3944

    
3945

    
3946
--
3947
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3948
--
3949

    
3950
ALTER TABLE ONLY map
3951
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3952

    
3953

    
3954
--
3955
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3956
--
3957

    
3958
ALTER TABLE ONLY map
3959
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3960

    
3961

    
3962
--
3963
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3964
--
3965

    
3966
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3967

    
3968

    
3969
--
3970
-- PostgreSQL database dump complete
3971
--
3972

    
(19-19/29)