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: auto_rm_freq(regclass, text); Type: FUNCTION; Schema: util; Owner: -
683
--
684

    
685
CREATE FUNCTION auto_rm_freq(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS void
686
    LANGUAGE sql
687
    AS $_$
688
SELECT CASE WHEN util.freq_always_1($1, $2) THEN util.drop_column(($1, $2)) END
689
$_$;
690

    
691

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

    
696
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
697
    LANGUAGE sql STABLE
698
    AS $_$
699
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
700
$_$;
701

    
702

    
703
--
704
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
705
--
706

    
707
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
708
    LANGUAGE plpgsql STRICT
709
    AS $_$
710
BEGIN
711
    -- not yet clustered (ARRAY[] compares NULLs literally)
712
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
713
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
714
    END IF;
715
END;
716
$_$;
717

    
718

    
719
--
720
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
721
--
722

    
723
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
724
idempotent
725
';
726

    
727

    
728
--
729
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
730
--
731

    
732
CREATE FUNCTION col__min(col col_ref) RETURNS integer
733
    LANGUAGE sql STABLE
734
    AS $_$
735
SELECT util.eval2val($$
736
SELECT $$||quote_ident($1.name)||$$
737
FROM $$||$1.table_||$$
738
ORDER BY $$||quote_ident($1.name)||$$ ASC
739
LIMIT 1
740
$$, NULL::integer)
741
$_$;
742

    
743

    
744
--
745
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
746
--
747

    
748
CREATE FUNCTION col_comment(col col_ref) RETURNS text
749
    LANGUAGE plpgsql STABLE STRICT
750
    AS $$
751
DECLARE
752
	comment text;
753
BEGIN
754
	SELECT description
755
	FROM pg_attribute
756
	LEFT JOIN pg_description ON objoid = attrelid
757
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
758
	WHERE attrelid = col.table_ AND attname = col.name
759
	INTO STRICT comment
760
	;
761
	RETURN comment;
762
EXCEPTION
763
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
764
END;
765
$$;
766

    
767

    
768
--
769
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
770
--
771

    
772
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
773
    LANGUAGE plpgsql STABLE STRICT
774
    AS $$
775
DECLARE
776
	default_sql text;
777
BEGIN
778
	SELECT adsrc
779
	FROM pg_attribute
780
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
781
	WHERE attrelid = col.table_ AND attname = col.name
782
	INTO STRICT default_sql
783
	;
784
	RETURN default_sql;
785
EXCEPTION
786
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
787
END;
788
$$;
789

    
790

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

    
795
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
796
    LANGUAGE sql STABLE
797
    AS $_$
798
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
799
$_$;
800

    
801

    
802
--
803
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
804
--
805

    
806
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
807
ret_type_null: NULL::ret_type
808
';
809

    
810

    
811
--
812
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
813
--
814

    
815
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
816
    LANGUAGE plpgsql STRICT
817
    AS $$
818
BEGIN
819
    PERFORM util.col_type(col);
820
    RETURN true;
821
EXCEPTION
822
    WHEN undefined_column THEN RETURN false;
823
END;
824
$$;
825

    
826

    
827
--
828
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
829
--
830

    
831
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
832
    LANGUAGE plpgsql STABLE STRICT
833
    AS $$
834
DECLARE
835
    prefix text := util.name(type)||'.';
836
BEGIN
837
    RETURN QUERY
838
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
839
        FROM util.col_names(type) f (name_);
840
END;
841
$$;
842

    
843

    
844
--
845
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
846
--
847

    
848
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
849
    LANGUAGE sql STABLE
850
    AS $_$
851
SELECT attname::text
852
FROM pg_attribute
853
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
854
ORDER BY attnum
855
$_$;
856

    
857

    
858
--
859
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
860
--
861

    
862
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
863
    LANGUAGE plpgsql STABLE STRICT
864
    AS $_$
865
BEGIN
866
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
867
END;
868
$_$;
869

    
870

    
871
--
872
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
873
--
874

    
875
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
876
    LANGUAGE plpgsql STABLE STRICT
877
    AS $$
878
DECLARE
879
    type regtype;
880
BEGIN
881
    SELECT atttypid FROM pg_attribute
882
    WHERE attrelid = col.table_ AND attname = col.name
883
    INTO STRICT type
884
    ;
885
    RETURN type;
886
EXCEPTION
887
    WHEN no_data_found THEN
888
        RAISE undefined_column USING MESSAGE =
889
            concat('undefined column: ', col.name);
890
END;
891
$$;
892

    
893

    
894
--
895
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
896
--
897

    
898
CREATE FUNCTION comment(element oid) RETURNS text
899
    LANGUAGE sql STABLE
900
    AS $_$
901
SELECT description FROM pg_description WHERE objoid = $1
902
$_$;
903

    
904

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

    
909
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
910
    LANGUAGE sql IMMUTABLE
911
    AS $_$
912
SELECT util.esc_name__append($2, $1)
913
$_$;
914

    
915

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

    
920
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
921
    LANGUAGE sql IMMUTABLE
922
    AS $_$
923
SELECT position($1 in $2) > 0 /*1-based offset*/
924
$_$;
925

    
926

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

    
931
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
932
    LANGUAGE sql
933
    AS $_$
934
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
935
$_$;
936

    
937

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

    
942
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
943
    LANGUAGE sql
944
    AS $_$
945
SELECT util.materialize_view($2, $1)
946
$_$;
947

    
948

    
949
--
950
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
951
--
952

    
953
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
954
    LANGUAGE plpgsql STRICT
955
    AS $$
956
BEGIN
957
	PERFORM util.eval(sql);
958
EXCEPTION
959
WHEN duplicate_table THEN NULL;
960
WHEN duplicate_object THEN NULL; -- e.g. constraint
961
WHEN duplicate_column THEN NULL;
962
WHEN duplicate_function THEN NULL;
963
WHEN invalid_table_definition THEN
964
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
965
	ELSE RAISE;
966
	END IF;
967
END;
968
$$;
969

    
970

    
971
--
972
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
973
--
974

    
975
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
976
idempotent
977
';
978

    
979

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

    
984
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
985
    LANGUAGE sql STABLE
986
    AS $$
987
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
988
$$;
989

    
990

    
991
--
992
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
993
--
994

    
995
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
996
    LANGUAGE sql IMMUTABLE
997
    AS $_$
998
SELECT util.raise('NOTICE', 'returns: '
999
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
1000
SELECT $1;
1001
$_$;
1002

    
1003

    
1004
--
1005
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1006
--
1007

    
1008
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1009
    LANGUAGE sql IMMUTABLE
1010
    AS $_$
1011
/* newline before so the query starts at the beginning of the line.
1012
newline after to visually separate queries from one another. */
1013
SELECT util.raise('NOTICE', $$
1014
$$||util.runnable_sql($1)||$$
1015
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1016
$_$;
1017

    
1018

    
1019
--
1020
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1021
--
1022

    
1023
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1024
    LANGUAGE sql STABLE
1025
    AS $_$
1026
SELECT util.eval2set($$
1027
SELECT col
1028
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1029
LEFT JOIN $$||$2||$$ ON "to" = col
1030
WHERE "from" IS NULL
1031
$$, NULL::text)
1032
$_$;
1033

    
1034

    
1035
--
1036
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1037
--
1038

    
1039
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1040
gets table_''s derived columns (all the columns not in the names table)
1041
';
1042

    
1043

    
1044
--
1045
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1046
--
1047

    
1048
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1049
    LANGUAGE sql
1050
    AS $_$
1051
-- create a diff when the # of copies of a row differs between the tables
1052
SELECT util.to_freq($1);
1053
SELECT util.to_freq($2);
1054
SELECT util.eval($$ALTER TABLE $$||util.typeof($3)||$$ ADD COLUMN copies bigint NOT NULL$$);
1055

    
1056
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1057
$_$;
1058

    
1059

    
1060
--
1061
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1062
--
1063

    
1064
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1065
usage:
1066
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1067

    
1068
col_type_null (*required*): NULL::shared_base_type
1069
';
1070

    
1071

    
1072
--
1073
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1074
--
1075

    
1076
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
1077
    LANGUAGE plpgsql
1078
    SET search_path TO pg_temp
1079
    AS $_$
1080
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1081
changes of search_path (schema elements are bound at inline time rather than
1082
runtime) */
1083
/* function option search_path is needed to limit the effects of
1084
`SET LOCAL search_path` to the current function */
1085
BEGIN
1086
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1087
	
1088
	PERFORM util.mk_keys_func(pg_typeof($3));
1089
	RETURN QUERY
1090
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1091
$$/* need to explicitly cast each side to the return type because this does not
1092
happen automatically even when an implicit cast is available */
1093
  left_::$$||util.typeof($3)||$$
1094
, right_::$$||util.typeof($3)
1095
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1096
the *same* base type, *even though* this is optional when using a custom %== */
1097
, util._if($4, $$true/*= CROSS JOIN*/$$,
1098
$$ left_::$$||util.typeof($3)||$$
1099
%== right_::$$||util.typeof($3)||$$
1100
	-- refer to EXPLAIN output for expansion of %==$$
1101
)), $3)
1102
	;
1103
END;
1104
$_$;
1105

    
1106

    
1107
--
1108
-- 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: -
1109
--
1110

    
1111
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1112
col_type_null (*required*): NULL::col_type
1113
single_row: whether the tables consist of a single row, which should be
1114
	displayed side-by-side
1115

    
1116
to match up rows using a subset of the columns, create a custom keys() function
1117
which returns this subset as a record:
1118
-- note that OUT parameters for the returned fields are *not* needed
1119
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1120
  RETURNS record AS
1121
$BODY$
1122
SELECT ($1.key_field_0, $1.key_field_1)
1123
$BODY$
1124
  LANGUAGE sql IMMUTABLE
1125
  COST 100;
1126

    
1127

    
1128
to run EXPLAIN on the FULL JOIN query:
1129
# run this function
1130
# look for a NOTICE containing the expanded query that it ran
1131
# run EXPLAIN on this expanded query
1132
';
1133

    
1134

    
1135
--
1136
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1137
--
1138

    
1139
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
1140
    LANGUAGE sql
1141
    AS $_$
1142
SELECT * FROM util.diff($1::text, $2::text, $3,
1143
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1144
$_$;
1145

    
1146

    
1147
--
1148
-- 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: -
1149
--
1150

    
1151
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1152
helper function used by diff(regclass, regclass)
1153

    
1154
usage:
1155
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1156

    
1157
col_type_null (*required*): NULL::shared_base_type
1158
';
1159

    
1160

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

    
1165
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1166
    LANGUAGE sql
1167
    AS $_$
1168
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1169
$_$;
1170

    
1171

    
1172
--
1173
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1174
--
1175

    
1176
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1177
idempotent
1178
';
1179

    
1180

    
1181
--
1182
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1183
--
1184

    
1185
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1186
    LANGUAGE sql
1187
    AS $_$
1188
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1189
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1190
$_$;
1191

    
1192

    
1193
--
1194
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1195
--
1196

    
1197
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1198
idempotent
1199
';
1200

    
1201

    
1202
--
1203
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1204
--
1205

    
1206
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1207
    LANGUAGE sql
1208
    AS $_$
1209
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1210
included in the debug SQL */
1211
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1212
$_$;
1213

    
1214

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

    
1219
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1220
    LANGUAGE sql
1221
    AS $_$
1222
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1223
||util._if($3, $$ CASCADE$$, ''::text))
1224
$_$;
1225

    
1226

    
1227
--
1228
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1229
--
1230

    
1231
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1232
idempotent
1233
';
1234

    
1235

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

    
1240
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1241
    LANGUAGE sql
1242
    AS $_$
1243
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1244
$_$;
1245

    
1246

    
1247
--
1248
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1249
--
1250

    
1251
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1252
    LANGUAGE sql
1253
    AS $_$
1254
SELECT util.drop_relation(relation, $3)
1255
FROM util.show_relations_like($1, $2) relation
1256
;
1257
SELECT NULL::void; -- don't fold away functions called in previous query
1258
$_$;
1259

    
1260

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

    
1265
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1266
    LANGUAGE sql
1267
    AS $_$
1268
SELECT util.drop_relation('TABLE', $1, $2)
1269
$_$;
1270

    
1271

    
1272
--
1273
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1274
--
1275

    
1276
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1277
idempotent
1278
';
1279

    
1280

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

    
1285
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1286
    LANGUAGE sql
1287
    AS $_$
1288
SELECT util.drop_relation('VIEW', $1, $2)
1289
$_$;
1290

    
1291

    
1292
--
1293
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1294
--
1295

    
1296
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1297
idempotent
1298
';
1299

    
1300

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

    
1305
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1306
    LANGUAGE sql IMMUTABLE
1307
    AS $_$
1308
SELECT util.array_fill($1, 0)
1309
$_$;
1310

    
1311

    
1312
--
1313
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1314
--
1315

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

    
1320

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

    
1325
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1326
    LANGUAGE sql IMMUTABLE
1327
    AS $_$
1328
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1329
$_$;
1330

    
1331

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

    
1336
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1337
    LANGUAGE sql IMMUTABLE
1338
    AS $_$
1339
SELECT regexp_replace($2, '("?)$', $1||'\1')
1340
$_$;
1341

    
1342

    
1343
--
1344
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1345
--
1346

    
1347
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1348
    LANGUAGE plpgsql
1349
    AS $$
1350
BEGIN
1351
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1352
	EXECUTE sql;
1353
END;
1354
$$;
1355

    
1356

    
1357
--
1358
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1359
--
1360

    
1361
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1362
    LANGUAGE plpgsql
1363
    AS $$
1364
BEGIN
1365
	PERFORM util.debug_print_sql(sql);
1366
	RETURN QUERY EXECUTE sql;
1367
END;
1368
$$;
1369

    
1370

    
1371
--
1372
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1373
--
1374

    
1375
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1376
col_type_null (*required*): NULL::col_type
1377
';
1378

    
1379

    
1380
--
1381
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1382
--
1383

    
1384
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1385
    LANGUAGE plpgsql
1386
    AS $$
1387
BEGIN
1388
	PERFORM util.debug_print_sql(sql);
1389
	RETURN QUERY EXECUTE sql;
1390
END;
1391
$$;
1392

    
1393

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

    
1398
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1399
    LANGUAGE plpgsql
1400
    AS $$
1401
BEGIN
1402
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1403
	RETURN QUERY EXECUTE sql;
1404
END;
1405
$$;
1406

    
1407

    
1408
--
1409
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1410
--
1411

    
1412
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1413
    LANGUAGE plpgsql STABLE
1414
    AS $$
1415
DECLARE
1416
	ret_val ret_type_null%TYPE;
1417
BEGIN
1418
	PERFORM util.debug_print_sql(sql);
1419
	EXECUTE sql INTO STRICT ret_val;
1420
	RETURN ret_val;
1421
END;
1422
$$;
1423

    
1424

    
1425
--
1426
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1427
--
1428

    
1429
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1430
ret_type_null: NULL::ret_type
1431
';
1432

    
1433

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

    
1438
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1439
    LANGUAGE sql
1440
    AS $_$
1441
SELECT util.eval2val($$SELECT $$||$1, $2)
1442
$_$;
1443

    
1444

    
1445
--
1446
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1447
--
1448

    
1449
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1450
ret_type_null: NULL::ret_type
1451
';
1452

    
1453

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

    
1458
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1459
    LANGUAGE sql
1460
    AS $_$
1461
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1462
$_$;
1463

    
1464

    
1465
--
1466
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1467
--
1468

    
1469
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1470
sql: can be NULL, which will be passed through
1471
ret_type_null: NULL::ret_type
1472
';
1473

    
1474

    
1475
--
1476
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1477
--
1478

    
1479
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1480
    LANGUAGE sql STABLE
1481
    AS $_$
1482
SELECT col_name
1483
FROM unnest($2) s (col_name)
1484
WHERE util.col_exists(($1, col_name))
1485
$_$;
1486

    
1487

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

    
1492
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1493
    LANGUAGE sql
1494
    AS $_$
1495
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1496
$_$;
1497

    
1498

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

    
1503
CREATE FUNCTION explain2notice(sql text) RETURNS void
1504
    LANGUAGE sql
1505
    AS $_$
1506
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1507
$_$;
1508

    
1509

    
1510
--
1511
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1512
--
1513

    
1514
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1515
    LANGUAGE sql
1516
    AS $_$
1517
-- newline before and after to visually separate it from other debug info
1518
SELECT $$
1519
EXPLAIN:
1520
$$||util.explain2str($1)||$$
1521
$$
1522
$_$;
1523

    
1524

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

    
1529
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1530
    LANGUAGE sql
1531
    AS $_$
1532
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1533
$_$;
1534

    
1535

    
1536
--
1537
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1538
--
1539

    
1540
CREATE FUNCTION explain2str(sql text) RETURNS text
1541
    LANGUAGE sql
1542
    AS $_$
1543
SELECT util.join_strs(explain, $$
1544
$$) FROM util.explain($1)
1545
$_$;
1546

    
1547

    
1548
SET default_tablespace = '';
1549

    
1550
SET default_with_oids = false;
1551

    
1552
--
1553
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1554
--
1555

    
1556
CREATE TABLE explain (
1557
    line text NOT NULL
1558
);
1559

    
1560

    
1561
--
1562
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1563
--
1564

    
1565
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1566
    LANGUAGE sql
1567
    AS $_$
1568
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1569
$$||quote_nullable($1)||$$
1570
)$$)
1571
$_$;
1572

    
1573

    
1574
--
1575
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1576
--
1577

    
1578
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1579
usage:
1580
PERFORM util.explain2table($$
1581
query
1582
$$);
1583
';
1584

    
1585

    
1586
--
1587
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1588
--
1589

    
1590
CREATE FUNCTION first_word(str text) RETURNS text
1591
    LANGUAGE sql IMMUTABLE
1592
    AS $_$
1593
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1594
$_$;
1595

    
1596

    
1597
--
1598
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1599
--
1600

    
1601
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1602
    LANGUAGE sql IMMUTABLE
1603
    AS $_$
1604
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1605
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1606
) END
1607
$_$;
1608

    
1609

    
1610
--
1611
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1612
--
1613

    
1614
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1615
ensures that an array will always have proper non-NULL dimensions
1616
';
1617

    
1618

    
1619
--
1620
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1621
--
1622

    
1623
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1624
    LANGUAGE plpgsql
1625
    AS $_$
1626
DECLARE
1627
	PG_EXCEPTION_DETAIL text;
1628
	recreate_users_cmd text = util.save_drop_views(users);
1629
BEGIN
1630
	PERFORM util.eval(cmd);
1631
	PERFORM util.eval(recreate_users_cmd);
1632
EXCEPTION
1633
WHEN dependent_objects_still_exist THEN
1634
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1635
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1636
	users = array(SELECT * FROM util.regexp_matches_group(
1637
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1638
	IF util.is_empty(users) THEN RAISE; END IF;
1639
	PERFORM util.force_recreate(cmd, users);
1640
END;
1641
$_$;
1642

    
1643

    
1644
--
1645
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1646
--
1647

    
1648
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1649
idempotent
1650

    
1651
users: not necessary to provide this because it will be autopopulated
1652
';
1653

    
1654

    
1655
--
1656
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1657
--
1658

    
1659
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1660
    LANGUAGE plpgsql STRICT
1661
    AS $_$
1662
DECLARE
1663
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1664
$$||query;
1665
BEGIN
1666
	EXECUTE mk_view;
1667
EXCEPTION
1668
WHEN invalid_table_definition THEN
1669
	IF SQLERRM = 'cannot drop columns from view'
1670
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1671
	THEN
1672
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1673
		EXECUTE mk_view;
1674
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1675
	END IF;
1676
END;
1677
$_$;
1678

    
1679

    
1680
--
1681
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1682
--
1683

    
1684
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1685
idempotent
1686
';
1687

    
1688

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

    
1693
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1694
    LANGUAGE sql STABLE
1695
    AS $_$
1696
SELECT util.eval2val(
1697
$$SELECT NOT EXISTS( -- there is no row that is != 1
1698
	SELECT NULL
1699
	FROM $$||$1||$$
1700
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1701
	LIMIT 1
1702
)
1703
$$, NULL::boolean)
1704
$_$;
1705

    
1706

    
1707
--
1708
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1709
--
1710

    
1711
CREATE FUNCTION grants_users() RETURNS SETOF text
1712
    LANGUAGE sql IMMUTABLE
1713
    AS $$
1714
VALUES ('bien_read'), ('public_')
1715
$$;
1716

    
1717

    
1718
--
1719
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1720
--
1721

    
1722
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1723
    LANGUAGE sql IMMUTABLE
1724
    AS $_$
1725
SELECT substring($2 for length($1)) = $1
1726
$_$;
1727

    
1728

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

    
1733
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1734
    LANGUAGE sql STABLE
1735
    AS $_$
1736
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1737
$_$;
1738

    
1739

    
1740
--
1741
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1742
--
1743

    
1744
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1745
    LANGUAGE sql IMMUTABLE
1746
    AS $_$
1747
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1748
$_$;
1749

    
1750

    
1751
--
1752
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1753
--
1754

    
1755
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1756
avoids repeating the same value for each key
1757
';
1758

    
1759

    
1760
--
1761
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1762
--
1763

    
1764
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1765
    LANGUAGE sql IMMUTABLE
1766
    AS $_$
1767
SELECT COALESCE($1, $2)
1768
$_$;
1769

    
1770

    
1771
--
1772
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1773
--
1774

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

    
1779

    
1780
--
1781
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1782
--
1783

    
1784
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1785
    LANGUAGE sql
1786
    AS $_$
1787
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1788
$_$;
1789

    
1790

    
1791
--
1792
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1793
--
1794

    
1795
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1796
    LANGUAGE sql STABLE
1797
    AS $_$
1798
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1799
$_$;
1800

    
1801

    
1802
--
1803
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1804
--
1805

    
1806
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1807
    LANGUAGE sql IMMUTABLE
1808
    AS $_$
1809
SELECT util.array_length($1) = 0
1810
$_$;
1811

    
1812

    
1813
--
1814
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1815
--
1816

    
1817
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1818
    LANGUAGE sql IMMUTABLE
1819
    AS $_$
1820
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1821
$_$;
1822

    
1823

    
1824
--
1825
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1826
--
1827

    
1828
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1829
    LANGUAGE sql IMMUTABLE
1830
    AS $_$
1831
SELECT upper(util.first_word($1)) = ANY(
1832
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1833
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1834
)
1835
$_$;
1836

    
1837

    
1838
--
1839
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1840
--
1841

    
1842
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1843
    LANGUAGE sql IMMUTABLE
1844
    AS $_$
1845
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1846
$_$;
1847

    
1848

    
1849
--
1850
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1851
--
1852

    
1853
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1854
    LANGUAGE sql IMMUTABLE
1855
    AS $_$
1856
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1857
$_$;
1858

    
1859

    
1860
--
1861
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1862
--
1863

    
1864
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1865
    LANGUAGE sql IMMUTABLE
1866
    AS $_$
1867
SELECT upper(util.first_word($1)) = 'SET'
1868
$_$;
1869

    
1870

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

    
1875
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1876
    LANGUAGE sql STABLE
1877
    AS $_$
1878
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1879
$_$;
1880

    
1881

    
1882
--
1883
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1884
--
1885

    
1886
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1887
    LANGUAGE sql STABLE
1888
    AS $_$
1889
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1890
$_$;
1891

    
1892

    
1893
--
1894
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1895
--
1896

    
1897
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1898
    LANGUAGE sql IMMUTABLE STRICT
1899
    AS $_$
1900
SELECT $1 || $3 || $2
1901
$_$;
1902

    
1903

    
1904
--
1905
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1906
--
1907

    
1908
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1909
must be declared STRICT to use the special handling of STRICT aggregating functions
1910
';
1911

    
1912

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

    
1917
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1918
    LANGUAGE sql IMMUTABLE
1919
    AS $_$
1920
SELECT $1 -- compare on the entire value
1921
$_$;
1922

    
1923

    
1924
--
1925
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1926
--
1927

    
1928
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1929
    LANGUAGE sql IMMUTABLE
1930
    AS $_$
1931
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1932
$_$;
1933

    
1934

    
1935
--
1936
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1937
--
1938

    
1939
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1940
    LANGUAGE sql IMMUTABLE
1941
    AS $_$
1942
SELECT ltrim($1, $$
1943
$$)
1944
$_$;
1945

    
1946

    
1947
--
1948
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
1949
--
1950

    
1951
CREATE FUNCTION map_filter_insert() RETURNS trigger
1952
    LANGUAGE plpgsql
1953
    AS $$
1954
BEGIN
1955
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
1956
	RETURN new;
1957
END;
1958
$$;
1959

    
1960

    
1961
--
1962
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1963
--
1964

    
1965
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
1966
    LANGUAGE plpgsql STABLE STRICT
1967
    AS $_$
1968
DECLARE
1969
    value text;
1970
BEGIN
1971
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
1972
        INTO value USING key;
1973
    RETURN value;
1974
END;
1975
$_$;
1976

    
1977

    
1978
--
1979
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
1980
--
1981

    
1982
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
1983
    LANGUAGE sql IMMUTABLE
1984
    AS $_$
1985
SELECT util._map(util.nulls_map($1), $2)
1986
$_$;
1987

    
1988

    
1989
--
1990
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
1991
--
1992

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

    
1996
[1] inlining of function calls, which is different from constant folding
1997
[2] _map()''s profiling query
1998
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
1999
and map_nulls()''s profiling query
2000
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2001
both take ~920 ms.
2002
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.
2003
';
2004

    
2005

    
2006
--
2007
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2008
--
2009

    
2010
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2011
    LANGUAGE plpgsql STABLE STRICT
2012
    AS $_$
2013
BEGIN
2014
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2015
END;
2016
$_$;
2017

    
2018

    
2019
--
2020
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2021
--
2022

    
2023
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2024
    LANGUAGE sql
2025
    AS $_$
2026
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2027
$$||util.ltrim_nl($2));
2028
-- make sure the created table has the correct estimated row count
2029
SELECT util.analyze_($1);
2030

    
2031
SELECT util.append_comment($1, '
2032
contents generated from:
2033
'||util.ltrim_nl($2)||';
2034
');
2035
$_$;
2036

    
2037

    
2038
--
2039
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2040
--
2041

    
2042
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2043
idempotent
2044
';
2045

    
2046

    
2047
--
2048
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2049
--
2050

    
2051
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2052
    LANGUAGE sql
2053
    AS $_$
2054
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2055
$_$;
2056

    
2057

    
2058
--
2059
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2060
--
2061

    
2062
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2063
idempotent
2064
';
2065

    
2066

    
2067
--
2068
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2069
--
2070

    
2071
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2072
    LANGUAGE sql
2073
    AS $_$
2074
SELECT util.create_if_not_exists($$
2075
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2076
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2077
||quote_literal($2)||$$;
2078
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2079
constant
2080
';
2081
$$)
2082
$_$;
2083

    
2084

    
2085
--
2086
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2087
--
2088

    
2089
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2090
idempotent
2091
';
2092

    
2093

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

    
2098
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2099
    LANGUAGE plpgsql STRICT
2100
    AS $_$
2101
DECLARE
2102
    type regtype = util.typeof(expr, col.table_::text::regtype);
2103
    col_name_sql text = quote_ident(col.name);
2104
BEGIN
2105
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2106
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2107
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2108
$$||expr||$$;
2109
$$);
2110
END;
2111
$_$;
2112

    
2113

    
2114
--
2115
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2116
--
2117

    
2118
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2119
idempotent
2120
';
2121

    
2122

    
2123
--
2124
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2125
--
2126

    
2127
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
2128
    LANGUAGE sql IMMUTABLE
2129
    AS $_$
2130
SELECT
2131
$$SELECT
2132
$$||$3||$$
2133
FROM      $$||$1||$$ left_
2134
FULL JOIN $$||$2||$$ right_
2135
ON $$||$4||$$
2136
WHERE $$||$5||$$
2137
ORDER BY left_, right_
2138
$$
2139
$_$;
2140

    
2141

    
2142
--
2143
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2144
--
2145

    
2146
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2147
    LANGUAGE sql
2148
    AS $_$
2149
-- keys()
2150
SELECT util.mk_keys_func($1, ARRAY(
2151
SELECT col FROM util.typed_cols($1) col
2152
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2153
));
2154

    
2155
-- values_()
2156
SELECT util.mk_keys_func($1, COALESCE(
2157
	NULLIF(ARRAY(
2158
	SELECT col FROM util.typed_cols($1) col
2159
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2160
	), ARRAY[]::util.col_cast[])
2161
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2162
, 'values_');
2163
$_$;
2164

    
2165

    
2166
--
2167
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2168
--
2169

    
2170
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2171
    LANGUAGE sql
2172
    AS $_$
2173
SELECT util.create_if_not_exists($$
2174
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2175
($$||util.mk_typed_cols_list($2)||$$);
2176
$$);
2177

    
2178
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2179
$_$;
2180

    
2181

    
2182
--
2183
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2184
--
2185

    
2186
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2187
    LANGUAGE sql
2188
    AS $_$
2189
SELECT util.create_if_not_exists($$
2190
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2191
||util.qual_name($1)||$$)
2192
  RETURNS $$||util.qual_name($2)||$$ AS
2193
$BODY1$
2194
SELECT ROW($$||
2195
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2196
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2197
$BODY1$
2198
  LANGUAGE sql IMMUTABLE
2199
  COST 100;
2200
$$);
2201
$_$;
2202

    
2203

    
2204
--
2205
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2206
--
2207

    
2208
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2209
    LANGUAGE sql
2210
    AS $_$
2211
SELECT util.create_if_not_exists($$
2212
CREATE TABLE $$||$1||$$
2213
(
2214
    LIKE util.map INCLUDING ALL
2215
);
2216

    
2217
CREATE TRIGGER map_filter_insert
2218
  BEFORE INSERT
2219
  ON $$||$1||$$
2220
  FOR EACH ROW
2221
  EXECUTE PROCEDURE util.map_filter_insert();
2222
$$)
2223
$_$;
2224

    
2225

    
2226
--
2227
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2228
--
2229

    
2230
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2231
    LANGUAGE sql IMMUTABLE
2232
    AS $_$
2233
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2234
util.qual_name((unnest).type), ''), '')
2235
FROM unnest($1)
2236
$_$;
2237

    
2238

    
2239
--
2240
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2241
--
2242

    
2243
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2244
    LANGUAGE sql IMMUTABLE
2245
    AS $_$
2246
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2247
$_$;
2248

    
2249

    
2250
--
2251
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2252
--
2253

    
2254
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2255
auto-appends util to the search_path to enable use of util operators
2256
';
2257

    
2258

    
2259
--
2260
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2261
--
2262

    
2263
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2264
    LANGUAGE sql IMMUTABLE
2265
    AS $_$
2266
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2267
$_$;
2268

    
2269

    
2270
--
2271
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2272
--
2273

    
2274
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2275
    LANGUAGE sql IMMUTABLE
2276
    AS $_$
2277
/* debug_print_return_value() needed because this function is used with EXECUTE
2278
rather than util.eval() (in order to affect the calling function), so the
2279
search_path would not otherwise be printed */
2280
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2281
||$$ search_path TO $$||$1
2282
$_$;
2283

    
2284

    
2285
--
2286
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2287
--
2288

    
2289
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2290
    LANGUAGE sql
2291
    AS $_$
2292
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2293
$_$;
2294

    
2295

    
2296
--
2297
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2298
--
2299

    
2300
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2301
idempotent
2302
';
2303

    
2304

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

    
2309
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2310
    LANGUAGE plpgsql STRICT
2311
    AS $_$
2312
DECLARE
2313
	view_qual_name text = util.qual_name(view_);
2314
BEGIN
2315
	EXECUTE $$
2316
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2317
  RETURNS SETOF $$||view_||$$ AS
2318
$BODY1$
2319
SELECT * FROM $$||view_qual_name||$$
2320
ORDER BY sort_col
2321
LIMIT $1 OFFSET $2
2322
$BODY1$
2323
  LANGUAGE sql STABLE
2324
  COST 100
2325
  ROWS 1000
2326
$$;
2327
	
2328
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2329
END;
2330
$_$;
2331

    
2332

    
2333
--
2334
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2335
--
2336

    
2337
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2338
    LANGUAGE plpgsql STRICT
2339
    AS $_$
2340
DECLARE
2341
	view_qual_name text = util.qual_name(view_);
2342
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2343
BEGIN
2344
	EXECUTE $$
2345
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2346
  RETURNS integer AS
2347
$BODY1$
2348
SELECT $$||quote_ident(row_num_col)||$$
2349
FROM $$||view_qual_name||$$
2350
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2351
LIMIT 1
2352
$BODY1$
2353
  LANGUAGE sql STABLE
2354
  COST 100;
2355
$$;
2356
	
2357
	EXECUTE $$
2358
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2359
  RETURNS SETOF $$||view_||$$ AS
2360
$BODY1$
2361
SELECT * FROM $$||view_qual_name||$$
2362
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2363
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2364
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2365
ORDER BY $$||quote_ident(row_num_col)||$$
2366
$BODY1$
2367
  LANGUAGE sql STABLE
2368
  COST 100
2369
  ROWS 1000
2370
$$;
2371
	
2372
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2373
END;
2374
$_$;
2375

    
2376

    
2377
--
2378
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2379
--
2380

    
2381
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2382
    LANGUAGE plpgsql STRICT
2383
    AS $_$
2384
DECLARE
2385
	view_qual_name text = util.qual_name(view_);
2386
BEGIN
2387
	EXECUTE $$
2388
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2389
  RETURNS SETOF $$||view_||$$
2390
  SET enable_sort TO 'off'
2391
  AS
2392
$BODY1$
2393
SELECT * FROM $$||view_qual_name||$$($2, $3)
2394
$BODY1$
2395
  LANGUAGE sql STABLE
2396
  COST 100
2397
  ROWS 1000
2398
;
2399
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2400
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2401
If you want to run EXPLAIN and get expanded output, use the regular subset
2402
function instead. (When a config param is set on a function, EXPLAIN produces
2403
just a function scan.)
2404
';
2405
$$;
2406
END;
2407
$_$;
2408

    
2409

    
2410
--
2411
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2412
--
2413

    
2414
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2415
creates subset function which turns off enable_sort
2416
';
2417

    
2418

    
2419
--
2420
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2421
--
2422

    
2423
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2424
    LANGUAGE sql IMMUTABLE
2425
    AS $_$
2426
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2427
util.qual_name((unnest).type), ', '), '')
2428
FROM unnest($1)
2429
$_$;
2430

    
2431

    
2432
--
2433
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2434
--
2435

    
2436
CREATE FUNCTION name(table_ regclass) RETURNS text
2437
    LANGUAGE sql STABLE
2438
    AS $_$
2439
SELECT relname::text FROM pg_class WHERE oid = $1
2440
$_$;
2441

    
2442

    
2443
--
2444
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2445
--
2446

    
2447
CREATE FUNCTION name(type regtype) RETURNS text
2448
    LANGUAGE sql STABLE
2449
    AS $_$
2450
SELECT typname::text FROM pg_type WHERE oid = $1
2451
$_$;
2452

    
2453

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

    
2458
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2459
    LANGUAGE sql IMMUTABLE
2460
    AS $_$
2461
SELECT octet_length($1) >= util.namedatalen() - $2
2462
$_$;
2463

    
2464

    
2465
--
2466
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2467
--
2468

    
2469
CREATE FUNCTION namedatalen() RETURNS integer
2470
    LANGUAGE sql IMMUTABLE
2471
    AS $$
2472
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2473
$$;
2474

    
2475

    
2476
--
2477
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2478
--
2479

    
2480
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2481
    LANGUAGE sql IMMUTABLE
2482
    AS $_$
2483
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2484
$_$;
2485

    
2486

    
2487
--
2488
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2489
--
2490

    
2491
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2492
    LANGUAGE sql IMMUTABLE
2493
    AS $_$
2494
SELECT $1 IS NOT NULL
2495
$_$;
2496

    
2497

    
2498
--
2499
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2500
--
2501

    
2502
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2503
    LANGUAGE sql IMMUTABLE
2504
    AS $_$
2505
SELECT util.hstore($1, NULL) || '*=>*'
2506
$_$;
2507

    
2508

    
2509
--
2510
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2511
--
2512

    
2513
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2514
for use with _map()
2515
';
2516

    
2517

    
2518
--
2519
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2520
--
2521

    
2522
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2523
    LANGUAGE sql IMMUTABLE
2524
    AS $_$
2525
SELECT $2 + COALESCE($1, 0)
2526
$_$;
2527

    
2528

    
2529
--
2530
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2531
--
2532

    
2533
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2534
    LANGUAGE sql
2535
    AS $_$
2536
SELECT util.eval($$INSERT INTO $$||$1||$$
2537
$$||util.ltrim_nl($2));
2538
-- make sure the created table has the correct estimated row count
2539
SELECT util.analyze_($1);
2540
$_$;
2541

    
2542

    
2543
--
2544
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2545
--
2546

    
2547
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2548
    LANGUAGE sql IMMUTABLE
2549
    AS $_$
2550
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2551
$_$;
2552

    
2553

    
2554
--
2555
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2556
--
2557

    
2558
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2559
    LANGUAGE sql
2560
    AS $_$
2561
SELECT util.set_comment($1, concat($2, util.comment($1)))
2562
$_$;
2563

    
2564

    
2565
--
2566
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2567
--
2568

    
2569
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2570
comment: must start and end with a newline
2571
';
2572

    
2573

    
2574
--
2575
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2576
--
2577

    
2578
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2579
    LANGUAGE sql IMMUTABLE
2580
    AS $_$
2581
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2582
$_$;
2583

    
2584

    
2585
--
2586
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2587
--
2588

    
2589
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2590
    LANGUAGE sql STABLE
2591
    SET search_path TO pg_temp
2592
    AS $_$
2593
SELECT $1::text
2594
$_$;
2595

    
2596

    
2597
--
2598
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2599
--
2600

    
2601
CREATE FUNCTION qual_name(type regtype) RETURNS text
2602
    LANGUAGE sql STABLE
2603
    SET search_path TO pg_temp
2604
    AS $_$
2605
SELECT $1::text
2606
$_$;
2607

    
2608

    
2609
--
2610
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2611
--
2612

    
2613
COMMENT ON FUNCTION qual_name(type regtype) IS '
2614
a type''s schema-qualified name
2615
';
2616

    
2617

    
2618
--
2619
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2620
--
2621

    
2622
CREATE FUNCTION qual_name(type unknown) RETURNS text
2623
    LANGUAGE sql STABLE
2624
    AS $_$
2625
SELECT util.qual_name($1::text::regtype)
2626
$_$;
2627

    
2628

    
2629
--
2630
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2631
--
2632

    
2633
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2634
    LANGUAGE sql IMMUTABLE
2635
    AS $_$
2636
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2637
$_$;
2638

    
2639

    
2640
--
2641
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2642
--
2643

    
2644
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2645
    LANGUAGE sql IMMUTABLE
2646
    AS $_$
2647
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2648
$_$;
2649

    
2650

    
2651
--
2652
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2653
--
2654

    
2655
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2656
    LANGUAGE sql IMMUTABLE
2657
    AS $_$
2658
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2659
$_$;
2660

    
2661

    
2662
--
2663
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2664
--
2665

    
2666
CREATE FUNCTION raise(type text, msg text) RETURNS void
2667
    LANGUAGE sql IMMUTABLE
2668
    AS $_X$
2669
SELECT util.eval($$
2670
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2671
  RETURNS void AS
2672
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2673
$__BODY1$
2674
BEGIN
2675
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2676
END;
2677
$__BODY1$
2678
  LANGUAGE plpgsql IMMUTABLE
2679
  COST 100;
2680
$$, verbose_ := false);
2681

    
2682
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2683
$_X$;
2684

    
2685

    
2686
--
2687
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2688
--
2689

    
2690
COMMENT ON FUNCTION raise(type text, msg text) IS '
2691
type: a log level from
2692
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2693
or a condition name from
2694
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2695
';
2696

    
2697

    
2698
--
2699
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2700
--
2701

    
2702
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2703
    LANGUAGE sql IMMUTABLE
2704
    AS $_$
2705
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2706
$_$;
2707

    
2708

    
2709
--
2710
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2711
--
2712

    
2713
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2714
    LANGUAGE plpgsql IMMUTABLE STRICT
2715
    AS $$
2716
BEGIN
2717
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2718
END;
2719
$$;
2720

    
2721

    
2722
--
2723
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2724
--
2725

    
2726
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2727
    LANGUAGE sql IMMUTABLE
2728
    AS $_$
2729
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2730
$_$;
2731

    
2732

    
2733
--
2734
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
2735
--
2736

    
2737
CREATE FUNCTION regexp_quote(str text) RETURNS text
2738
    LANGUAGE sql IMMUTABLE
2739
    AS $_$
2740
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2741
$_$;
2742

    
2743

    
2744
--
2745
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2746
--
2747

    
2748
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2749
    LANGUAGE sql IMMUTABLE
2750
    AS $_$
2751
SELECT (CASE WHEN right($1, 1) = ')'
2752
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2753
$_$;
2754

    
2755

    
2756
--
2757
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2758
--
2759

    
2760
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2761
    LANGUAGE sql STABLE
2762
    AS $_$
2763
SELECT util.relation_type(util.relation_type_char($1))
2764
$_$;
2765

    
2766

    
2767
--
2768
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2769
--
2770

    
2771
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2772
    LANGUAGE sql IMMUTABLE
2773
    AS $_$
2774
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2775
$_$;
2776

    
2777

    
2778
--
2779
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2780
--
2781

    
2782
CREATE FUNCTION relation_type(type regtype) RETURNS text
2783
    LANGUAGE sql IMMUTABLE
2784
    AS $$
2785
SELECT 'TYPE'::text
2786
$$;
2787

    
2788

    
2789
--
2790
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2791
--
2792

    
2793
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2794
    LANGUAGE sql STABLE
2795
    AS $_$
2796
SELECT relkind FROM pg_class WHERE oid = $1
2797
$_$;
2798

    
2799

    
2800
--
2801
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2802
--
2803

    
2804
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2805
    LANGUAGE sql
2806
    AS $_$
2807
/* can't have in_table/out_table inherit from *each other*, because inheritance
2808
also causes the rows of the parent table to be included in the child table.
2809
instead, they need to inherit from a common, empty table. */
2810
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2811
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2812
SELECT util.inherit($2, $4);
2813
SELECT util.inherit($3, $4);
2814

    
2815
SELECT util.rematerialize_query($1, $$
2816
SELECT * FROM util.diff(
2817
  $$||util.quote_typed($2)||$$
2818
, $$||util.quote_typed($3)||$$
2819
, NULL::$$||$4||$$)
2820
$$);
2821

    
2822
/* the table unfortunately cannot be *materialized* in human-readable form,
2823
because this would create column name collisions between the two sides */
2824
SELECT util.prepend_comment($1, '
2825
to view this table in human-readable form (with each side''s tuple column
2826
expanded to its component fields):
2827
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2828
');
2829
$_$;
2830

    
2831

    
2832
--
2833
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2834
--
2835

    
2836
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2837
type_table (*required*): table to create as the shared base type
2838
';
2839

    
2840

    
2841
--
2842
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2843
--
2844

    
2845
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2846
    LANGUAGE sql
2847
    AS $_$
2848
SELECT util.drop_table($1);
2849
SELECT util.materialize_query($1, $2);
2850
$_$;
2851

    
2852

    
2853
--
2854
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2855
--
2856

    
2857
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2858
idempotent, but repeats action each time
2859
';
2860

    
2861

    
2862
--
2863
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2864
--
2865

    
2866
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2867
    LANGUAGE sql
2868
    AS $_$
2869
SELECT util.drop_table($1);
2870
SELECT util.materialize_view($1, $2);
2871
$_$;
2872

    
2873

    
2874
--
2875
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2876
--
2877

    
2878
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2879
idempotent, but repeats action each time
2880
';
2881

    
2882

    
2883
--
2884
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2885
--
2886

    
2887
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2888
    LANGUAGE sql
2889
    AS $_$
2890
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2891
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2892
FROM util.col_names($1::text::regtype) f (name);
2893
SELECT NULL::void; -- don't fold away functions called in previous query
2894
$_$;
2895

    
2896

    
2897
--
2898
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2899
--
2900

    
2901
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2902
idempotent
2903
';
2904

    
2905

    
2906
--
2907
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2908
--
2909

    
2910
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2911
    LANGUAGE sql
2912
    AS $_$
2913
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2914
included in the debug SQL */
2915
SELECT util.rename_relation(util.qual_name($1), $2)
2916
$_$;
2917

    
2918

    
2919
--
2920
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2921
--
2922

    
2923
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2924
    LANGUAGE sql
2925
    AS $_$
2926
/* 'ALTER TABLE can be used with views too'
2927
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2928
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2929
||quote_ident($2))
2930
$_$;
2931

    
2932

    
2933
--
2934
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
2935
--
2936

    
2937
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
2938
idempotent
2939
';
2940

    
2941

    
2942
--
2943
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2944
--
2945

    
2946
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
2947
    LANGUAGE sql IMMUTABLE
2948
    AS $_$
2949
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
2950
$_$;
2951

    
2952

    
2953
--
2954
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
2955
--
2956

    
2957
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
2958
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 
2959
';
2960

    
2961

    
2962
--
2963
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2964
--
2965

    
2966
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
2967
    LANGUAGE sql
2968
    AS $_$
2969
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
2970
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
2971
SELECT util.set_col_names($1, $2);
2972
$_$;
2973

    
2974

    
2975
--
2976
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
2977
--
2978

    
2979
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
2980
idempotent.
2981
alters the names table, so it will need to be repopulated after running this function.
2982
';
2983

    
2984

    
2985
--
2986
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2987
--
2988

    
2989
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
2990
    LANGUAGE sql
2991
    AS $_$
2992
SELECT util.drop_table($1);
2993
SELECT util.mk_map_table($1);
2994
$_$;
2995

    
2996

    
2997
--
2998
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
2999
--
3000

    
3001
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3002
    LANGUAGE sql IMMUTABLE
3003
    AS $_$
3004
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3005
$_$;
3006

    
3007

    
3008
--
3009
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3010
--
3011

    
3012
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3013
    LANGUAGE sql IMMUTABLE
3014
    AS $_$
3015
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3016
ELSE util.mk_set_search_path(for_printing := true)||$$;
3017
$$ END)||$1
3018
$_$;
3019

    
3020

    
3021
--
3022
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3023
--
3024

    
3025
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3026
    LANGUAGE plpgsql STRICT
3027
    AS $_$
3028
DECLARE
3029
	result text = NULL;
3030
BEGIN
3031
	BEGIN
3032
		result = util.show_create_view(view_);
3033
		PERFORM util.eval($$DROP VIEW $$||view_);
3034
	EXCEPTION
3035
		WHEN undefined_table THEN NULL;
3036
	END;
3037
	RETURN result;
3038
END;
3039
$_$;
3040

    
3041

    
3042
--
3043
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3044
--
3045

    
3046
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3047
    LANGUAGE sql
3048
    AS $_$
3049
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3050
$_$;
3051

    
3052

    
3053
--
3054
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3055
--
3056

    
3057
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3058
    LANGUAGE sql STABLE
3059
    AS $_$
3060
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3061
$_$;
3062

    
3063

    
3064
--
3065
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3066
--
3067

    
3068
CREATE FUNCTION schema(table_ regclass) RETURNS text
3069
    LANGUAGE sql STABLE
3070
    AS $_$
3071
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3072
$_$;
3073

    
3074

    
3075
--
3076
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3077
--
3078

    
3079
CREATE FUNCTION schema(type regtype) RETURNS text
3080
    LANGUAGE sql STABLE
3081
    AS $_$
3082
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3083
$_$;
3084

    
3085

    
3086
--
3087
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3088
--
3089

    
3090
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3091
    LANGUAGE sql STABLE
3092
    AS $_$
3093
SELECT util.schema(pg_typeof($1))
3094
$_$;
3095

    
3096

    
3097
--
3098
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3099
--
3100

    
3101
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3102
    LANGUAGE sql STABLE
3103
    AS $_$
3104
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3105
$_$;
3106

    
3107

    
3108
--
3109
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3110
--
3111

    
3112
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3113
a schema bundle is a group of schemas with a common prefix
3114
';
3115

    
3116

    
3117
--
3118
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3119
--
3120

    
3121
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3122
    LANGUAGE sql
3123
    AS $_$
3124
SELECT util.schema_rename(old_schema,
3125
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3126
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3127
SELECT NULL::void; -- don't fold away functions called in previous query
3128
$_$;
3129

    
3130

    
3131
--
3132
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3133
--
3134

    
3135
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3136
    LANGUAGE plpgsql
3137
    AS $$
3138
BEGIN
3139
	-- don't schema_bundle_rm() the schema_bundle to keep!
3140
	IF replace = with_ THEN RETURN; END IF;
3141
	
3142
	PERFORM util.schema_bundle_rm(replace);
3143
	PERFORM util.schema_bundle_rename(with_, replace);
3144
END;
3145
$$;
3146

    
3147

    
3148
--
3149
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3150
--
3151

    
3152
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3153
    LANGUAGE sql
3154
    AS $_$
3155
SELECT util.schema_rm(schema)
3156
FROM util.schema_bundle_get_schemas($1) f (schema);
3157
SELECT NULL::void; -- don't fold away functions called in previous query
3158
$_$;
3159

    
3160

    
3161
--
3162
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3163
--
3164

    
3165
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3166
    LANGUAGE sql STABLE
3167
    AS $_$
3168
SELECT quote_ident(util.schema($1))
3169
$_$;
3170

    
3171

    
3172
--
3173
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3174
--
3175

    
3176
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3177
    LANGUAGE sql IMMUTABLE
3178
    AS $_$
3179
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3180
$_$;
3181

    
3182

    
3183
--
3184
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3185
--
3186

    
3187
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3188
    LANGUAGE sql STABLE
3189
    AS $_$
3190
SELECT oid FROM pg_namespace WHERE nspname = $1
3191
$_$;
3192

    
3193

    
3194
--
3195
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3196
--
3197

    
3198
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3199
    LANGUAGE sql IMMUTABLE
3200
    AS $_$
3201
SELECT util.schema_regexp(schema_anchor := $1)
3202
$_$;
3203

    
3204

    
3205
--
3206
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3207
--
3208

    
3209
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3210
    LANGUAGE sql IMMUTABLE
3211
    AS $_$
3212
SELECT util.str_equality_regexp(util.schema($1))
3213
$_$;
3214

    
3215

    
3216
--
3217
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3218
--
3219

    
3220
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3221
    LANGUAGE sql
3222
    AS $_$
3223
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3224
$_$;
3225

    
3226

    
3227
--
3228
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3229
--
3230

    
3231
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3232
    LANGUAGE plpgsql
3233
    AS $$
3234
BEGIN
3235
	-- don't schema_rm() the schema to keep!
3236
	IF replace = with_ THEN RETURN; END IF;
3237
	
3238
	PERFORM util.schema_rm(replace);
3239
	PERFORM util.schema_rename(with_, replace);
3240
END;
3241
$$;
3242

    
3243

    
3244
--
3245
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3246
--
3247

    
3248
CREATE FUNCTION schema_rm(schema text) RETURNS void
3249
    LANGUAGE sql
3250
    AS $_$
3251
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3252
$_$;
3253

    
3254

    
3255
--
3256
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3257
--
3258

    
3259
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3260
    LANGUAGE sql
3261
    AS $_$
3262
SELECT util.eval(
3263
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3264
$_$;
3265

    
3266

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

    
3271
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3272
    LANGUAGE plpgsql STRICT
3273
    AS $_$
3274
DECLARE
3275
    old text[] = ARRAY(SELECT util.col_names(table_));
3276
    new text[] = ARRAY(SELECT util.map_values(names));
3277
BEGIN
3278
    old = old[1:array_length(new, 1)]; -- truncate to same length
3279
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3280
||$$ TO $$||quote_ident(value))
3281
    FROM each(hstore(old, new))
3282
    WHERE value != key -- not same name
3283
    ;
3284
END;
3285
$_$;
3286

    
3287

    
3288
--
3289
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3290
--
3291

    
3292
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3293
idempotent
3294
';
3295

    
3296

    
3297
--
3298
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3299
--
3300

    
3301
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3302
    LANGUAGE plpgsql STRICT
3303
    AS $_$
3304
DECLARE
3305
	row_ util.map;
3306
BEGIN
3307
	-- rename any metadata cols rather than re-adding them with new names
3308
	BEGIN
3309
		PERFORM util.set_col_names(table_, names);
3310
	EXCEPTION
3311
		WHEN array_subscript_error THEN -- selective suppress
3312
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3313
				-- metadata cols not yet added
3314
			ELSE RAISE;
3315
			END IF;
3316
	END;
3317
	
3318
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3319
	LOOP
3320
		PERFORM util.mk_const_col((table_, row_."to"),
3321
			substring(row_."from" from 2));
3322
	END LOOP;
3323
	
3324
	PERFORM util.set_col_names(table_, names);
3325
END;
3326
$_$;
3327

    
3328

    
3329
--
3330
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3331
--
3332

    
3333
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3334
idempotent.
3335
the metadata mappings must be *last* in the names table.
3336
';
3337

    
3338

    
3339
--
3340
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3341
--
3342

    
3343
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3344
    LANGUAGE plpgsql STRICT
3345
    AS $_$
3346
DECLARE
3347
    sql text = $$ALTER TABLE $$||table_||$$
3348
$$||NULLIF(array_to_string(ARRAY(
3349
    SELECT
3350
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3351
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3352
    FROM
3353
    (
3354
        SELECT
3355
          quote_ident(col_name) AS col_name_sql
3356
        , util.col_type((table_, col_name)) AS curr_type
3357
        , type AS target_type
3358
        FROM unnest(col_casts)
3359
    ) s
3360
    WHERE curr_type != target_type
3361
), '
3362
, '), '');
3363
BEGIN
3364
    PERFORM util.debug_print_sql(sql);
3365
    EXECUTE COALESCE(sql, '');
3366
END;
3367
$_$;
3368

    
3369

    
3370
--
3371
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3372
--
3373

    
3374
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3375
idempotent
3376
';
3377

    
3378

    
3379
--
3380
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3381
--
3382

    
3383
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3384
    LANGUAGE sql
3385
    AS $_$
3386
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3387
$_$;
3388

    
3389

    
3390
--
3391
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3392
--
3393

    
3394
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3395
    LANGUAGE sql
3396
    AS $_$
3397
SELECT util.eval(util.mk_set_search_path($1, $2))
3398
$_$;
3399

    
3400

    
3401
--
3402
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3403
--
3404

    
3405
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3406
    LANGUAGE sql STABLE
3407
    AS $_$
3408
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3409
$$||util.show_grants_for($1)
3410
$_$;
3411

    
3412

    
3413
--
3414
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3415
--
3416

    
3417
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3418
    LANGUAGE sql STABLE
3419
    AS $_$
3420
SELECT string_agg(cmd, '')
3421
FROM
3422
(
3423
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3424
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3425
$$ ELSE '' END) AS cmd
3426
	FROM util.grants_users() f (user_)
3427
) s
3428
$_$;
3429

    
3430

    
3431
--
3432
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3433
--
3434

    
3435
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['r'::text, 'v'::text]) RETURNS SETOF regclass
3436
    LANGUAGE sql STABLE
3437
    AS $_$
3438
SELECT oid FROM pg_class
3439
WHERE relkind = ANY($3) AND relname ~ $1
3440
AND util.schema_matches(util.schema(relnamespace), $2)
3441
ORDER BY relname
3442
$_$;
3443

    
3444

    
3445
--
3446
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3447
--
3448

    
3449
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3450
    LANGUAGE sql STABLE
3451
    AS $_$
3452
SELECT oid
3453
FROM pg_type
3454
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3455
ORDER BY typname
3456
$_$;
3457

    
3458

    
3459
--
3460
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3461
--
3462

    
3463
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3464
    LANGUAGE sql STABLE
3465
    AS $_$
3466
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3467
$_$;
3468

    
3469

    
3470
--
3471
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3472
--
3473

    
3474
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3475
    LANGUAGE sql IMMUTABLE
3476
    AS $_$
3477
SELECT '^'||util.regexp_quote($1)||'$'
3478
$_$;
3479

    
3480

    
3481
--
3482
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3483
--
3484

    
3485
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3486
    LANGUAGE plpgsql STABLE STRICT
3487
    AS $_$
3488
DECLARE
3489
    hstore hstore;
3490
BEGIN
3491
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3492
        table_||$$))$$ INTO STRICT hstore;
3493
    RETURN hstore;
3494
END;
3495
$_$;
3496

    
3497

    
3498
--
3499
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3500
--
3501

    
3502
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3503
    LANGUAGE sql STABLE
3504
    AS $_$
3505
SELECT COUNT(*) > 0 FROM pg_constraint
3506
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3507
$_$;
3508

    
3509

    
3510
--
3511
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3512
--
3513

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

    
3518

    
3519
--
3520
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3521
--
3522

    
3523
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3524
    LANGUAGE sql
3525
    AS $_$
3526
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3527
||quote_ident($2)||$$ CHECK (true)$$)
3528
$_$;
3529

    
3530

    
3531
--
3532
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3533
--
3534

    
3535
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3536
stores a status flag by the presence of a table constraint.
3537
idempotent.
3538
';
3539

    
3540

    
3541
--
3542
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3543
--
3544

    
3545
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3546
    LANGUAGE sql STABLE
3547
    AS $_$
3548
SELECT util.table_flag__get($1, 'nulls_mapped')
3549
$_$;
3550

    
3551

    
3552
--
3553
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3554
--
3555

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

    
3560

    
3561
--
3562
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3563
--
3564

    
3565
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3566
    LANGUAGE sql
3567
    AS $_$
3568
SELECT util.table_flag__set($1, 'nulls_mapped')
3569
$_$;
3570

    
3571

    
3572
--
3573
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3574
--
3575

    
3576
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3577
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3578
idempotent.
3579
';
3580

    
3581

    
3582
--
3583
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3584
--
3585

    
3586
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3587
    LANGUAGE sql
3588
    AS $_$
3589
-- save data before truncating main table
3590
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3591

    
3592
-- repopulate main table w/ copies column
3593
SELECT util.truncate($1);
3594
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3595
SELECT util.populate_table($1, $$
3596
SELECT (table_).*, copies
3597
FROM (
3598
	SELECT table_, COUNT(*) AS copies
3599
	FROM pg_temp.__copy table_
3600
	GROUP BY table_
3601
) s
3602
$$);
3603

    
3604
-- delete temp table so it doesn't stay around until end of connection
3605
SELECT util.drop_table('pg_temp.__copy');
3606
$_$;
3607

    
3608

    
3609
--
3610
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3611
--
3612

    
3613
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3614
    LANGUAGE plpgsql STRICT
3615
    AS $_$
3616
DECLARE
3617
    row record;
3618
BEGIN
3619
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3620
    LOOP
3621
        IF row.global_name != row.name THEN
3622
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3623
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3624
        END IF;
3625
    END LOOP;
3626
END;
3627
$_$;
3628

    
3629

    
3630
--
3631
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3632
--
3633

    
3634
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3635
idempotent
3636
';
3637

    
3638

    
3639
--
3640
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3641
--
3642

    
3643
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3644
    LANGUAGE sql
3645
    AS $_$
3646
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3647
SELECT NULL::void; -- don't fold away functions called in previous query
3648
$_$;
3649

    
3650

    
3651
--
3652
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3653
--
3654

    
3655
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3656
trims table_ to include only columns in the original data.
3657
idempotent.
3658
';
3659

    
3660

    
3661
--
3662
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3663
--
3664

    
3665
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3666
    LANGUAGE plpgsql STRICT
3667
    AS $_$
3668
BEGIN
3669
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3670
END;
3671
$_$;
3672

    
3673

    
3674
--
3675
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3676
--
3677

    
3678
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3679
idempotent
3680
';
3681

    
3682

    
3683
--
3684
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3685
--
3686

    
3687
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3688
    LANGUAGE sql IMMUTABLE
3689
    AS $_$
3690
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3691
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3692
$_$;
3693

    
3694

    
3695
--
3696
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3697
--
3698

    
3699
CREATE FUNCTION try_create(sql text) RETURNS void
3700
    LANGUAGE plpgsql STRICT
3701
    AS $$
3702
BEGIN
3703
    PERFORM util.eval(sql);
3704
EXCEPTION
3705
    WHEN wrong_object_type THEN NULL; -- trying to alter a view's columns
3706
    WHEN undefined_column THEN NULL;
3707
    WHEN duplicate_column THEN NULL;
3708
END;
3709
$$;
3710

    
3711

    
3712
--
3713
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3714
--
3715

    
3716
COMMENT ON FUNCTION try_create(sql text) IS '
3717
idempotent
3718
';
3719

    
3720

    
3721
--
3722
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3723
--
3724

    
3725
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3726
    LANGUAGE sql
3727
    AS $_$
3728
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3729
$_$;
3730

    
3731

    
3732
--
3733
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3734
--
3735

    
3736
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3737
idempotent
3738
';
3739

    
3740

    
3741
--
3742
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3743
--
3744

    
3745
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3746
    LANGUAGE sql IMMUTABLE
3747
    AS $_$
3748
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3749
$_$;
3750

    
3751

    
3752
--
3753
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3754
--
3755

    
3756
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3757
a type''s NOT NULL qualifier
3758
';
3759

    
3760

    
3761
--
3762
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3763
--
3764

    
3765
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3766
    LANGUAGE sql STABLE
3767
    AS $_$
3768
SELECT (attname::text, atttypid)::util.col_cast
3769
FROM pg_attribute
3770
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3771
ORDER BY attnum
3772
$_$;
3773

    
3774

    
3775
--
3776
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3777
--
3778

    
3779
CREATE FUNCTION typeof(value anyelement) RETURNS text
3780
    LANGUAGE sql IMMUTABLE
3781
    AS $_$
3782
SELECT util.qual_name(pg_typeof($1))
3783
$_$;
3784

    
3785

    
3786
--
3787
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3788
--
3789

    
3790
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3791
    LANGUAGE plpgsql STABLE
3792
    AS $_$
3793
DECLARE
3794
    type regtype;
3795
BEGIN
3796
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3797
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3798
    RETURN type;
3799
END;
3800
$_$;
3801

    
3802

    
3803
--
3804
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3805
--
3806

    
3807
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3808
    LANGUAGE sql
3809
    AS $_$
3810
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3811
$_$;
3812

    
3813

    
3814
--
3815
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3816
--
3817

    
3818
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3819
auto-appends util to the search_path to enable use of util operators
3820
';
3821

    
3822

    
3823
--
3824
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3825
--
3826

    
3827
CREATE AGGREGATE all_same(anyelement) (
3828
    SFUNC = all_same_transform,
3829
    STYPE = anyarray,
3830
    FINALFUNC = all_same_final
3831
);
3832

    
3833

    
3834
--
3835
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3836
--
3837

    
3838
COMMENT ON AGGREGATE all_same(anyelement) IS '
3839
includes NULLs in comparison
3840
';
3841

    
3842

    
3843
--
3844
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3845
--
3846

    
3847
CREATE AGGREGATE join_strs(text, text) (
3848
    SFUNC = join_strs_transform,
3849
    STYPE = text
3850
);
3851

    
3852

    
3853
--
3854
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3855
--
3856

    
3857
CREATE OPERATOR %== (
3858
    PROCEDURE = "%==",
3859
    LEFTARG = anyelement,
3860
    RIGHTARG = anyelement
3861
);
3862

    
3863

    
3864
--
3865
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3866
--
3867

    
3868
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3869
returns whether the map-keys of the compared values are the same
3870
(mnemonic: % is the Perl symbol for a hash map)
3871

    
3872
should be overridden for types that store both keys and values
3873

    
3874
used in a FULL JOIN to select which columns to join on
3875
';
3876

    
3877

    
3878
--
3879
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3880
--
3881

    
3882
CREATE OPERATOR -> (
3883
    PROCEDURE = map_get,
3884
    LEFTARG = regclass,
3885
    RIGHTARG = text
3886
);
3887

    
3888

    
3889
--
3890
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3891
--
3892

    
3893
CREATE OPERATOR => (
3894
    PROCEDURE = hstore,
3895
    LEFTARG = text[],
3896
    RIGHTARG = text
3897
);
3898

    
3899

    
3900
--
3901
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3902
--
3903

    
3904
COMMENT ON OPERATOR => (text[], text) IS '
3905
usage: array[''key1'', ...]::text[] => ''value''
3906
';
3907

    
3908

    
3909
--
3910
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3911
--
3912

    
3913
CREATE OPERATOR ?*>= (
3914
    PROCEDURE = is_populated_more_often_than,
3915
    LEFTARG = anyelement,
3916
    RIGHTARG = anyelement
3917
);
3918

    
3919

    
3920
--
3921
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3922
--
3923

    
3924
CREATE OPERATOR ?>= (
3925
    PROCEDURE = is_more_complete_than,
3926
    LEFTARG = anyelement,
3927
    RIGHTARG = anyelement
3928
);
3929

    
3930

    
3931
--
3932
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
3933
--
3934

    
3935
CREATE OPERATOR ||% (
3936
    PROCEDURE = concat_esc,
3937
    LEFTARG = text,
3938
    RIGHTARG = text
3939
);
3940

    
3941

    
3942
--
3943
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
3944
--
3945

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

    
3950

    
3951
--
3952
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
3953
--
3954

    
3955
CREATE TABLE map (
3956
    "from" text NOT NULL,
3957
    "to" text,
3958
    filter text,
3959
    notes text
3960
);
3961

    
3962

    
3963
--
3964
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
3965
--
3966

    
3967

    
3968

    
3969
--
3970
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
3971
--
3972

    
3973

    
3974

    
3975
--
3976
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3977
--
3978

    
3979
ALTER TABLE ONLY map
3980
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
3981

    
3982

    
3983
--
3984
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
3985
--
3986

    
3987
ALTER TABLE ONLY map
3988
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
3989

    
3990

    
3991
--
3992
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
3993
--
3994

    
3995
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
3996

    
3997

    
3998
--
3999
-- PostgreSQL database dump complete
4000
--
4001

    
(19-19/29)