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: db_item; Type: TYPE; Schema: util; Owner: -
76
--
77

    
78
CREATE TYPE db_item AS (
79
	path text,
80
	def text
81
);
82

    
83

    
84
--
85
-- Name: restore_views_info; Type: TYPE; Schema: util; Owner: -
86
--
87

    
88
CREATE TYPE restore_views_info AS (
89
	views db_item[]
90
);
91

    
92

    
93
--
94
-- Name: %==(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
95
--
96

    
97
CREATE FUNCTION "%=="(left_ anyelement, right_ anyelement) RETURNS boolean
98
    LANGUAGE sql STABLE
99
    AS $_$
100
SELECT keys($1) = keys($2)
101
$_$;
102

    
103

    
104
--
105
-- Name: FUNCTION "%=="(left_ anyelement, right_ anyelement); Type: COMMENT; Schema: util; Owner: -
106
--
107

    
108
COMMENT ON FUNCTION "%=="(left_ anyelement, right_ anyelement) IS '
109
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**)
110
';
111

    
112

    
113
--
114
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
115
--
116

    
117
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
118
    LANGUAGE sql IMMUTABLE
119
    AS $_$
120
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
121
$_$;
122

    
123

    
124
--
125
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
126
--
127

    
128
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
129
    LANGUAGE sql IMMUTABLE
130
    AS $_$
131
SELECT bool_and(value)
132
FROM
133
(VALUES
134
      ($1)
135
    , ($2)
136
    , ($3)
137
    , ($4)
138
    , ($5)
139
)
140
AS v (value)
141
$_$;
142

    
143

    
144
--
145
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
146
--
147

    
148
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
149
_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.
150
';
151

    
152

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

    
157
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
158
    LANGUAGE sql IMMUTABLE
159
    AS $_$
160
SELECT avg(value)
161
FROM
162
(VALUES
163
      ($1)
164
    , ($2)
165
    , ($3)
166
    , ($4)
167
    , ($5)
168
)
169
AS v (value)
170
$_$;
171

    
172

    
173
--
174
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: util; Owner: -
175
--
176

    
177
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
178
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
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)
181
FROM 
182
(
183
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
184
    UNION ALL
185
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
186
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
187
)
188
matches (g)
189
$_$;
190

    
191

    
192
--
193
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: util; Owner: -
194
--
195

    
196
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
197
    LANGUAGE sql IMMUTABLE
198
    AS $_$
199
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
200
FROM
201
(VALUES
202
      ($1)
203
    , ($2/60)
204
    , ($3/60/60)
205
)
206
AS v (value)
207
$_$;
208

    
209

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

    
214
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
215
    LANGUAGE sql IMMUTABLE
216
    AS $_$
217
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
218
$_$;
219

    
220

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

    
225
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
226
    LANGUAGE sql IMMUTABLE
227
    AS $_$
228
SELECT $1 = $2
229
$_$;
230

    
231

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

    
236
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
237
    LANGUAGE sql IMMUTABLE
238
    AS $_$
239
-- Fix dates after threshold date
240
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
241
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
242
$_$;
243

    
244

    
245
--
246
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
247
--
248

    
249
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
250
    LANGUAGE sql IMMUTABLE
251
    AS $_$
252
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
253
$_$;
254

    
255

    
256
--
257
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
258
--
259

    
260
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
261
    LANGUAGE sql IMMUTABLE
262
    AS $_$
263
SELECT util._if($1 != '', $2, $3)
264
$_$;
265

    
266

    
267
--
268
-- Name: _join(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
269
--
270

    
271
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
272
    LANGUAGE sql IMMUTABLE
273
    AS $_$
274
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
275
$_$;
276

    
277

    
278
--
279
-- Name: _join_words(text, text, text, text, text, text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
280
--
281

    
282
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
283
    LANGUAGE sql IMMUTABLE
284
    AS $_$
285
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
286
$_$;
287

    
288

    
289
--
290
-- Name: _km_to_m(double precision); Type: FUNCTION; Schema: util; Owner: -
291
--
292

    
293
CREATE FUNCTION _km_to_m(value double precision) RETURNS double precision
294
    LANGUAGE sql IMMUTABLE
295
    AS $_$
296
SELECT $1*1000.
297
$_$;
298

    
299

    
300
--
301
-- Name: _label(text, text); Type: FUNCTION; Schema: util; Owner: -
302
--
303

    
304
CREATE FUNCTION _label(label text, value text) RETURNS text
305
    LANGUAGE sql IMMUTABLE
306
    AS $_$
307
SELECT coalesce($1 || ': ', '') || $2
308
$_$;
309

    
310

    
311
--
312
-- Name: _lowercase(text); Type: FUNCTION; Schema: util; Owner: -
313
--
314

    
315
CREATE FUNCTION _lowercase(value text) RETURNS text
316
    LANGUAGE sql IMMUTABLE
317
    AS $_$
318
SELECT lower($1)
319
$_$;
320

    
321

    
322
--
323
-- Name: _map(hstore, anyelement); Type: FUNCTION; Schema: util; Owner: -
324
--
325

    
326
CREATE FUNCTION _map(map hstore, value anyelement) RETURNS anyelement
327
    LANGUAGE plpgsql IMMUTABLE STRICT
328
    AS $$
329
DECLARE
330
    result value%TYPE := util._map(map, value::text)::unknown;
331
BEGIN
332
    RETURN result;
333
END;
334
$$;
335

    
336

    
337
--
338
-- Name: _map(hstore, text); Type: FUNCTION; Schema: util; Owner: -
339
--
340

    
341
CREATE FUNCTION _map(map hstore, value text) RETURNS text
342
    LANGUAGE plpgsql IMMUTABLE STRICT
343
    AS $$
344
DECLARE
345
    match text := map -> value;
346
BEGIN
347
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
348
        match := map -> '*'; -- use default entry
349
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
350
        END IF;
351
    END IF;
352
    
353
    -- Interpret result
354
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
355
    ELSIF match = '*' THEN RETURN value;
356
    ELSE RETURN match;
357
    END IF;
358
END;
359
$$;
360

    
361

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

    
366
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
367
    LANGUAGE sql IMMUTABLE
368
    AS $_$
369
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
370
$_$;
371

    
372

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

    
377
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
378
    LANGUAGE sql IMMUTABLE
379
    AS $_$
380
SELECT util.join_strs(value, '; ')
381
FROM
382
(
383
    SELECT *
384
    FROM
385
    (
386
        SELECT
387
        DISTINCT ON (value)
388
        *
389
        FROM
390
        (VALUES
391
              (1, $1)
392
            , (2, $2)
393
            , (3, $3)
394
            , (4, $4)
395
            , (5, $5)
396
            , (6, $6)
397
            , (7, $7)
398
            , (8, $8)
399
            , (9, $9)
400
            , (10, $10)
401
        )
402
        AS v (sort_order, value)
403
        WHERE value IS NOT NULL
404
    )
405
    AS v
406
    ORDER BY sort_order
407
)
408
AS v
409
$_$;
410

    
411

    
412
--
413
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
414
--
415

    
416
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
417
    LANGUAGE sql IMMUTABLE
418
    AS $_$
419
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
420
$_$;
421

    
422

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

    
427
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
428
    LANGUAGE sql IMMUTABLE
429
    AS $_$
430
SELECT util.join_strs(value, ' ')
431
FROM
432
(
433
    SELECT *
434
    FROM
435
    (
436
        SELECT
437
        DISTINCT ON (value)
438
        *
439
        FROM
440
        (VALUES
441
              (1, $1)
442
            , (2, $2)
443
            , (3, $3)
444
            , (4, $4)
445
            , (5, $5)
446
            , (6, $6)
447
            , (7, $7)
448
            , (8, $8)
449
            , (9, $9)
450
            , (10, $10)
451
        )
452
        AS v (sort_order, value)
453
        WHERE value IS NOT NULL
454
    )
455
    AS v
456
    ORDER BY sort_order
457
)
458
AS v
459
$_$;
460

    
461

    
462
--
463
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
464
--
465

    
466
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
467
    LANGUAGE sql IMMUTABLE
468
    AS $_$
469
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
470
$_$;
471

    
472

    
473
--
474
-- Name: _not(boolean); Type: FUNCTION; Schema: util; Owner: -
475
--
476

    
477
CREATE FUNCTION _not(value boolean) RETURNS boolean
478
    LANGUAGE sql IMMUTABLE
479
    AS $_$
480
SELECT NOT $1
481
$_$;
482

    
483

    
484
--
485
-- Name: _now(); Type: FUNCTION; Schema: util; Owner: -
486
--
487

    
488
CREATE FUNCTION _now() RETURNS timestamp with time zone
489
    LANGUAGE sql STABLE
490
    AS $$
491
SELECT now()
492
$$;
493

    
494

    
495
--
496
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: util; Owner: -
497
--
498

    
499
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
500
    LANGUAGE sql IMMUTABLE
501
    AS $_$
502
SELECT util."_nullIf"($1, $2, $3::util.datatype)
503
$_$;
504

    
505

    
506
--
507
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: util; Owner: -
508
--
509

    
510
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
511
    LANGUAGE plpgsql IMMUTABLE
512
    AS $$
513
DECLARE
514
    type util.datatype NOT NULL := type; -- add NOT NULL
515
BEGIN
516
    IF type = 'str' THEN RETURN nullif(value::text, "null");
517
    -- Invalid value is ignored, but invalid null value generates error
518
    ELSIF type = 'float' THEN
519
        DECLARE
520
            -- Outside the try block so that invalid null value generates error
521
            "null" double precision := "null"::double precision;
522
        BEGIN
523
            RETURN nullif(value::double precision, "null");
524
        EXCEPTION
525
            WHEN data_exception THEN RETURN value; -- ignore invalid value
526
        END;
527
    END IF;
528
END;
529
$$;
530

    
531

    
532
--
533
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: util; Owner: -
534
--
535

    
536
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
537
    LANGUAGE sql IMMUTABLE
538
    AS $_$
539
SELECT bool_or(value)
540
FROM
541
(VALUES
542
      ($1)
543
    , ($2)
544
    , ($3)
545
    , ($4)
546
    , ($5)
547
)
548
AS v (value)
549
$_$;
550

    
551

    
552
--
553
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: util; Owner: -
554
--
555

    
556
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
557
_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.
558
';
559

    
560

    
561
--
562
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: util; Owner: -
563
--
564

    
565
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
566
    LANGUAGE sql IMMUTABLE
567
    AS $_$
568
SELECT $2 - $1
569
$_$;
570

    
571

    
572
--
573
-- Name: _split(text, text); Type: FUNCTION; Schema: util; Owner: -
574
--
575

    
576
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
577
    LANGUAGE sql IMMUTABLE
578
    AS $_$
579
SELECT regexp_split_to_table($1, $2)
580
$_$;
581

    
582

    
583
--
584
-- Name: added_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
585
--
586

    
587
CREATE FUNCTION added_cols(table_ regclass, names regclass) RETURNS SETOF text
588
    LANGUAGE sql STABLE
589
    AS $_$
590
SELECT util.derived_cols($1, $2)
591
UNION
592
SELECT util.eval2set($$
593
SELECT col
594
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
595
JOIN $$||$2||$$ ON "to" = col
596
WHERE "from" LIKE ':%'
597
$$, NULL::text)
598
$_$;
599

    
600

    
601
--
602
-- Name: FUNCTION added_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
603
--
604

    
605
COMMENT ON FUNCTION added_cols(table_ regclass, names regclass) IS '
606
gets table_''s added columns (all the columns not in the original data)
607
';
608

    
609

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

    
614
CREATE FUNCTION all_same_final(state anyarray) RETURNS boolean
615
    LANGUAGE sql IMMUTABLE
616
    AS $_$
617
SELECT $1 IS NULL/*no rows*/ OR util.not_empty($1)/*not no_match_sentinel*/
618
$_$;
619

    
620

    
621
--
622
-- Name: all_same_transform(anyarray, anyelement); Type: FUNCTION; Schema: util; Owner: -
623
--
624

    
625
CREATE FUNCTION all_same_transform(state anyarray, value anyelement) RETURNS anyarray
626
    LANGUAGE plpgsql IMMUTABLE
627
    AS $$
628
DECLARE
629
	value_cmp         state%TYPE = ARRAY[value];
630
	state             state%TYPE = COALESCE(state, value_cmp);
631
	no_match_sentinel state%TYPE = value_cmp[1:0]/*=ARRAY[]::state%TYPE*/;
632
BEGIN
633
	RETURN (CASE WHEN value_cmp IS NOT DISTINCT FROM state THEN state ELSE no_match_sentinel END);
634
END;
635
$$;
636

    
637

    
638
--
639
-- Name: analyze_(regclass); Type: FUNCTION; Schema: util; Owner: -
640
--
641

    
642
CREATE FUNCTION analyze_(table_ regclass) RETURNS void
643
    LANGUAGE sql
644
    AS $_$
645
SELECT util.eval($$ANALYZE VERBOSE $$||$1)
646
$_$;
647

    
648

    
649
--
650
-- Name: append_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
651
--
652

    
653
CREATE FUNCTION append_comment(table_ regclass, comment text) RETURNS void
654
    LANGUAGE sql
655
    AS $_$
656
SELECT util.set_comment($1, concat(util.comment($1), $2))
657
$_$;
658

    
659

    
660
--
661
-- Name: FUNCTION append_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
662
--
663

    
664
COMMENT ON FUNCTION append_comment(table_ regclass, comment text) IS '
665
comment: must start and end with a newline
666
';
667

    
668

    
669
--
670
-- Name: array_fill(anyelement, integer); Type: FUNCTION; Schema: util; Owner: -
671
--
672

    
673
CREATE FUNCTION array_fill(value anyelement, length integer) RETURNS anyarray
674
    LANGUAGE sql IMMUTABLE
675
    AS $_$
676
SELECT pg_catalog.array_fill($1, ARRAY[$2])
677
$_$;
678

    
679

    
680
--
681
-- Name: array_length(anyarray); Type: FUNCTION; Schema: util; Owner: -
682
--
683

    
684
CREATE FUNCTION array_length("array" anyarray) RETURNS integer
685
    LANGUAGE sql IMMUTABLE
686
    AS $_$
687
SELECT util.array_length($1, 1)
688
$_$;
689

    
690

    
691
--
692
-- Name: array_length(anyarray, integer); Type: FUNCTION; Schema: util; Owner: -
693
--
694

    
695
CREATE FUNCTION array_length("array" anyarray, dimension integer) RETURNS integer
696
    LANGUAGE sql IMMUTABLE
697
    AS $_$
698
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE COALESCE(pg_catalog.array_length($1, $2), 0) END
699
$_$;
700

    
701

    
702
--
703
-- Name: FUNCTION array_length("array" anyarray, dimension integer); Type: COMMENT; Schema: util; Owner: -
704
--
705

    
706
COMMENT ON FUNCTION array_length("array" anyarray, dimension integer) IS '
707
returns 0 instead of NULL for empty arrays
708
';
709

    
710

    
711
--
712
-- Name: array_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
713
--
714

    
715
CREATE FUNCTION array_reverse("array" anyarray) RETURNS anyarray
716
    LANGUAGE sql IMMUTABLE
717
    AS $_$
718
SELECT array(SELECT elem FROM util.in_reverse($1) elem)
719
$_$;
720

    
721

    
722
--
723
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
724
--
725

    
726
CREATE FUNCTION auto_rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
727
    LANGUAGE sql
728
    AS $_$
729
SELECT CASE WHEN util.freq_always_1($1, $2)
730
THEN util.rm_freq($1, $2)
731
ELSE util.try_create($$ALTER TABLE $$||util.parent($1[1])||$$ ADD COLUMN $$||quote_ident($2)||$$ bigint NOT NULL$$)
732
END
733
$_$;
734

    
735

    
736
--
737
-- Name: cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
738
--
739

    
740
CREATE FUNCTION "cast"(value text, ret_type_null anyelement) RETURNS anyelement
741
    LANGUAGE plpgsql IMMUTABLE
742
    AS $$
743
/* must use LANGUAGE plpgsql because LANGUAGE sql does not assignment-cast the
744
return value, causing a type mismatch */
745
BEGIN
746
	-- will then be assignment-cast to return type via INOUT
747
	RETURN value::cstring;
748
END;
749
$$;
750

    
751

    
752
--
753
-- Name: FUNCTION "cast"(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
754
--
755

    
756
COMMENT ON FUNCTION "cast"(value text, ret_type_null anyelement) IS '
757
allows casting to an arbitrary type without eval()
758

    
759
usage:
760
SELECT util.cast(''value'', NULL::integer);
761

    
762
note that there does *not* need to be a cast from text to the output type,
763
because an INOUT cast is used instead
764
(http://www.postgresql.org/docs/9.3/static/sql-createcast.html#AEN69507)
765

    
766
ret_type_null: NULL::ret_type
767
';
768

    
769

    
770
--
771
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
772
--
773

    
774
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
775
    LANGUAGE sql STABLE
776
    AS $_$
777
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
778
$_$;
779

    
780

    
781
--
782
-- Name: cluster_once(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
783
--
784

    
785
CREATE FUNCTION cluster_once(table_ regclass, index regclass) RETURNS void
786
    LANGUAGE plpgsql STRICT
787
    AS $_$
788
BEGIN
789
    -- not yet clustered (ARRAY[] compares NULLs literally)
790
    IF ARRAY[util.cluster_index(table_)] != ARRAY[index] THEN
791
        EXECUTE $$CLUSTER $$||table_||$$ USING $$||index;
792
    END IF;
793
END;
794
$_$;
795

    
796

    
797
--
798
-- Name: FUNCTION cluster_once(table_ regclass, index regclass); Type: COMMENT; Schema: util; Owner: -
799
--
800

    
801
COMMENT ON FUNCTION cluster_once(table_ regclass, index regclass) IS '
802
idempotent
803
';
804

    
805

    
806
--
807
-- Name: coalesce(anyarray); Type: FUNCTION; Schema: util; Owner: -
808
--
809

    
810
CREATE FUNCTION "coalesce"(VARIADIC values_ anyarray) RETURNS anyelement
811
    LANGUAGE sql IMMUTABLE
812
    AS $_$
813
SELECT value
814
FROM unnest($1) value
815
WHERE value IS NOT NULL
816
LIMIT 1
817
$_$;
818

    
819

    
820
--
821
-- Name: FUNCTION "coalesce"(VARIADIC values_ anyarray); Type: COMMENT; Schema: util; Owner: -
822
--
823

    
824
COMMENT ON FUNCTION "coalesce"(VARIADIC values_ anyarray) IS '
825
uses:
826
* coalescing array elements or rows together
827
* forcing evaluation of all values of a COALESCE()
828
';
829

    
830

    
831
--
832
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
833
--
834

    
835
CREATE FUNCTION col__min(col col_ref) RETURNS integer
836
    LANGUAGE sql STABLE
837
    AS $_$
838
SELECT util.eval2val($$
839
SELECT $$||quote_ident($1.name)||$$
840
FROM $$||$1.table_||$$
841
ORDER BY $$||quote_ident($1.name)||$$ ASC
842
LIMIT 1
843
$$, NULL::integer)
844
$_$;
845

    
846

    
847
--
848
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
849
--
850

    
851
CREATE FUNCTION col_comment(col col_ref) RETURNS text
852
    LANGUAGE plpgsql STABLE STRICT
853
    AS $$
854
DECLARE
855
	comment text;
856
BEGIN
857
	SELECT description
858
	FROM pg_attribute
859
	LEFT JOIN pg_description ON objoid = attrelid
860
		AND classoid = 'pg_class'::regclass AND objsubid = attnum
861
	WHERE attrelid = col.table_ AND attname = col.name
862
	INTO STRICT comment
863
	;
864
	RETURN comment;
865
EXCEPTION
866
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
867
END;
868
$$;
869

    
870

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

    
875
CREATE FUNCTION col_default_sql(col col_ref) RETURNS text
876
    LANGUAGE plpgsql STABLE STRICT
877
    AS $$
878
DECLARE
879
	default_sql text;
880
BEGIN
881
	SELECT adsrc
882
	FROM pg_attribute
883
	LEFT JOIN pg_attrdef ON adrelid = attrelid AND adnum = attnum
884
	WHERE attrelid = col.table_ AND attname = col.name
885
	INTO STRICT default_sql
886
	;
887
	RETURN default_sql;
888
EXCEPTION
889
	WHEN no_data_found THEN PERFORM util.raise_undefined_column(col);
890
END;
891
$$;
892

    
893

    
894
--
895
-- Name: col_default_value(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
896
--
897

    
898
CREATE FUNCTION col_default_value(col col_ref, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
899
    LANGUAGE sql STABLE
900
    AS $_$
901
SELECT util.eval_expr_passthru(util.col_default_sql($1), $2)
902
$_$;
903

    
904

    
905
--
906
-- Name: FUNCTION col_default_value(col col_ref, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
907
--
908

    
909
COMMENT ON FUNCTION col_default_value(col col_ref, ret_type_null anyelement) IS '
910
ret_type_null: NULL::ret_type
911
';
912

    
913

    
914
--
915
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
916
--
917

    
918
CREATE FUNCTION col_exists(col col_ref) RETURNS boolean
919
    LANGUAGE plpgsql STRICT
920
    AS $$
921
BEGIN
922
    PERFORM util.col_type(col);
923
    RETURN true;
924
EXCEPTION
925
    WHEN undefined_column THEN RETURN false;
926
END;
927
$$;
928

    
929

    
930
--
931
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
932
--
933

    
934
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
935
    LANGUAGE plpgsql STABLE STRICT
936
    AS $$
937
DECLARE
938
    prefix text := util.name(type)||'.';
939
BEGIN
940
    RETURN QUERY
941
        SELECT name_, (CASE WHEN util.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
942
        FROM util.col_names(type) f (name_);
943
END;
944
$$;
945

    
946

    
947
--
948
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
949
--
950

    
951
CREATE FUNCTION col_names(table_ regclass) RETURNS SETOF text
952
    LANGUAGE sql STABLE
953
    AS $_$
954
SELECT attname::text
955
FROM pg_attribute
956
WHERE attrelid = $1 AND attnum >= 1 AND NOT attisdropped
957
ORDER BY attnum
958
$_$;
959

    
960

    
961
--
962
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
963
--
964

    
965
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
966
    LANGUAGE plpgsql STABLE STRICT
967
    AS $_$
968
BEGIN
969
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
970
END;
971
$_$;
972

    
973

    
974
--
975
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
976
--
977

    
978
CREATE FUNCTION col_type(col col_ref) RETURNS regtype
979
    LANGUAGE plpgsql STABLE STRICT
980
    AS $$
981
DECLARE
982
    type regtype;
983
BEGIN
984
    SELECT atttypid FROM pg_attribute
985
    WHERE attrelid = col.table_ AND attname = col.name
986
    INTO STRICT type
987
    ;
988
    RETURN type;
989
EXCEPTION
990
    WHEN no_data_found THEN
991
        RAISE undefined_column USING MESSAGE =
992
            concat('undefined column: ', col.name);
993
END;
994
$$;
995

    
996

    
997
--
998
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
999
--
1000

    
1001
CREATE FUNCTION comment(element oid) RETURNS text
1002
    LANGUAGE sql STABLE
1003
    AS $_$
1004
SELECT description FROM pg_description WHERE objoid = $1
1005
$_$;
1006

    
1007

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

    
1012
CREATE FUNCTION concat_esc("left" text, "right" text) RETURNS text
1013
    LANGUAGE sql IMMUTABLE
1014
    AS $_$
1015
SELECT util.esc_name__append($2, $1)
1016
$_$;
1017

    
1018

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

    
1023
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
1024
    LANGUAGE sql IMMUTABLE
1025
    AS $_$
1026
SELECT position($1 in $2) > 0 /*1-based offset*/
1027
$_$;
1028

    
1029

    
1030
--
1031
-- Name: copy(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1032
--
1033

    
1034
CREATE FUNCTION copy(from_ regclass, to_ text) RETURNS void
1035
    LANGUAGE sql
1036
    AS $_$
1037
SELECT util.copy_struct($1, $2);
1038
SELECT util.copy_data($1, $2);
1039
$_$;
1040

    
1041

    
1042
--
1043
-- Name: copy_data(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1044
--
1045

    
1046
CREATE FUNCTION copy_data(from_ regclass, to_ regclass) RETURNS void
1047
    LANGUAGE sql
1048
    AS $_$
1049
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT * FROM $$||$1)
1050
$_$;
1051

    
1052

    
1053
--
1054
-- Name: copy_struct(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1055
--
1056

    
1057
CREATE FUNCTION copy_struct(from_ regclass, to_ text) RETURNS void
1058
    LANGUAGE sql
1059
    AS $_$
1060
SELECT util.eval($$CREATE TABLE $$||$2||$$ (LIKE $$||$1||$$ INCLUDING ALL)$$)
1061
$_$;
1062

    
1063

    
1064
--
1065
-- Name: copy_types_and_data(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1066
--
1067

    
1068
CREATE FUNCTION copy_types_and_data(from_ regclass, to_ text) RETURNS void
1069
    LANGUAGE sql
1070
    AS $_$
1071
SELECT util.materialize_view($2, $1)
1072
$_$;
1073

    
1074

    
1075
--
1076
-- Name: create_if_not_exists(text, text); Type: FUNCTION; Schema: util; Owner: -
1077
--
1078

    
1079
CREATE FUNCTION create_if_not_exists(sql text, relation text DEFAULT NULL::text) RETURNS void
1080
    LANGUAGE plpgsql
1081
    AS $$
1082
BEGIN
1083
	/* always generate standard exception if exists, even if table definition
1084
	would be invalid (which generates a variety of exceptions) */
1085
	IF util.relation_exists(relation) THEN
1086
		PERFORM util.raise('NOTICE', relation||' already exists, skipping');
1087
		RAISE duplicate_table;
1088
	END IF;
1089
	PERFORM util.eval(sql);
1090
EXCEPTION
1091
WHEN   duplicate_table
1092
	OR duplicate_object -- eg. constraint
1093
	OR duplicate_column
1094
	OR duplicate_function
1095
THEN NULL;
1096
WHEN invalid_table_definition THEN
1097
	IF SQLERRM LIKE 'multiple primary keys for table % are not allowed' THEN NULL;
1098
	ELSE RAISE;
1099
	END IF;
1100
END;
1101
$$;
1102

    
1103

    
1104
--
1105
-- Name: FUNCTION create_if_not_exists(sql text, relation text); Type: COMMENT; Schema: util; Owner: -
1106
--
1107

    
1108
COMMENT ON FUNCTION create_if_not_exists(sql text, relation text) IS '
1109
idempotent
1110
';
1111

    
1112

    
1113
--
1114
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1115
--
1116

    
1117
CREATE FUNCTION curr_func(func text, schema_anchor anyelement) RETURNS text
1118
    LANGUAGE sql STABLE
1119
    AS $$
1120
SELECT util.schema_esc(schema_anchor)||'.'||quote_ident(func)
1121
$$;
1122

    
1123

    
1124
--
1125
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
1126
--
1127

    
1128
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
1129
    LANGUAGE sql IMMUTABLE
1130
    AS $_$
1131
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1132
$_$;
1133

    
1134

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

    
1139
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1140
    LANGUAGE sql IMMUTABLE
1141
    AS $_$
1142
SELECT util.debug_print_value('returns: ', $1, $2);
1143
SELECT $1;
1144
$_$;
1145

    
1146

    
1147
--
1148
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1149
--
1150

    
1151
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1152
    LANGUAGE sql IMMUTABLE
1153
    AS $_$
1154
/* newline before so the query starts at the beginning of the line.
1155
newline after to visually separate queries from one another. */
1156
SELECT util.raise('NOTICE', $$
1157
$$||util.runnable_sql($1)||$$
1158
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1159
$_$;
1160

    
1161

    
1162
--
1163
-- Name: debug_print_value(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1164
--
1165

    
1166
CREATE FUNCTION debug_print_value(label text, value anyelement, encode boolean DEFAULT false) RETURNS void
1167
    LANGUAGE sql IMMUTABLE
1168
    AS $_$
1169
SELECT util.raise('NOTICE', concat($1,
1170
(CASE WHEN $3 THEN util.quote_typed($2) ELSE $2::text END))||$$
1171
$$)
1172
$_$;
1173

    
1174

    
1175
--
1176
-- Name: debug_print_var(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1177
--
1178

    
1179
CREATE FUNCTION debug_print_var(var text, value anyelement, encode boolean DEFAULT false) RETURNS void
1180
    LANGUAGE sql IMMUTABLE
1181
    AS $_$
1182
/* can't use EXECUTE in the caller because "No substitution of PL/pgSQL
1183
variables is done on the computed command string"
1184
(http://www.postgresql.org/docs/9.3/static/plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN) */
1185
SELECT util.debug_print_value($1||' = ', $2, $3)
1186
$_$;
1187

    
1188

    
1189
--
1190
-- Name: derived_cols(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
1191
--
1192

    
1193
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1194
    LANGUAGE sql STABLE
1195
    AS $_$
1196
SELECT util.eval2set($$
1197
SELECT col
1198
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1199
LEFT JOIN $$||$2||$$ ON "to" = col
1200
WHERE "from" IS NULL
1201
$$, NULL::text)
1202
$_$;
1203

    
1204

    
1205
--
1206
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1207
--
1208

    
1209
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1210
gets table_''s derived columns (all the columns not in the names table)
1211
';
1212

    
1213

    
1214
--
1215
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1216
--
1217

    
1218
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1219
    LANGUAGE sql
1220
    AS $_$
1221
-- create a diff when the # of copies of a row differs between the tables
1222
SELECT util.to_freq($1);
1223
SELECT util.to_freq($2);
1224
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1225

    
1226
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1227
$_$;
1228

    
1229

    
1230
--
1231
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1232
--
1233

    
1234
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1235
usage:
1236
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1237

    
1238
col_type_null (*required*): NULL::shared_base_type
1239
';
1240

    
1241

    
1242
--
1243
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1244
--
1245

    
1246
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
1247
    LANGUAGE plpgsql
1248
    SET search_path TO pg_temp
1249
    AS $_$
1250
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1251
changes of search_path (schema elements are bound at inline time rather than
1252
runtime) */
1253
/* function option search_path is needed to limit the effects of
1254
`SET LOCAL search_path` to the current function */
1255
BEGIN
1256
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1257
	
1258
	PERFORM util.mk_keys_func(pg_typeof($3));
1259
	RETURN QUERY
1260
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1261
$$/* need to explicitly cast each side to the return type because this does not
1262
happen automatically even when an implicit cast is available */
1263
  left_::$$||util.typeof($3)||$$
1264
, right_::$$||util.typeof($3)
1265
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1266
the *same* base type, *even though* this is optional when using a custom %== */
1267
, util._if($4, $$true/*= CROSS JOIN*/$$,
1268
$$ left_::$$||util.typeof($3)||$$
1269
%== right_::$$||util.typeof($3)||$$
1270
	-- refer to EXPLAIN output for expansion of %==$$
1271
)
1272
,     $$         left_::$$||util.typeof($3)||$$
1273
IS DISTINCT FROM right_::$$||util.typeof($3)
1274
), $3)
1275
	;
1276
END;
1277
$_$;
1278

    
1279

    
1280
--
1281
-- 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: -
1282
--
1283

    
1284
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1285
col_type_null (*required*): NULL::col_type
1286
single_row: whether the tables consist of a single row, which should be
1287
	displayed side-by-side
1288

    
1289
to match up rows using a subset of the columns, create a custom keys() function
1290
which returns this subset as a record:
1291
-- note that OUT parameters for the returned fields are *not* needed
1292
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1293
  RETURNS record AS
1294
$BODY$
1295
SELECT ($1.key_field_0, $1.key_field_1)
1296
$BODY$
1297
  LANGUAGE sql IMMUTABLE
1298
  COST 100;
1299

    
1300

    
1301
to run EXPLAIN on the FULL JOIN query:
1302
# run this function
1303
# look for a NOTICE containing the expanded query that it ran
1304
# run EXPLAIN on this expanded query
1305
';
1306

    
1307

    
1308
--
1309
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1310
--
1311

    
1312
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
1313
    LANGUAGE sql
1314
    AS $_$
1315
SELECT * FROM util.diff($1::text, $2::text, $3,
1316
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1317
$_$;
1318

    
1319

    
1320
--
1321
-- 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: -
1322
--
1323

    
1324
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1325
helper function used by diff(regclass, regclass)
1326

    
1327
usage:
1328
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1329

    
1330
col_type_null (*required*): NULL::shared_base_type
1331
';
1332

    
1333

    
1334
--
1335
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1336
--
1337

    
1338
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1339
    LANGUAGE sql
1340
    AS $_$
1341
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1342
$_$;
1343

    
1344

    
1345
--
1346
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1347
--
1348

    
1349
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1350
idempotent
1351
';
1352

    
1353

    
1354
--
1355
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1356
--
1357

    
1358
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1359
    LANGUAGE sql
1360
    AS $_$
1361
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1362
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1363
$_$;
1364

    
1365

    
1366
--
1367
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1368
--
1369

    
1370
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1371
idempotent
1372
';
1373

    
1374

    
1375
--
1376
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1377
--
1378

    
1379
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1380
    LANGUAGE sql
1381
    AS $_$
1382
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_;
1383
SELECT NULL::void; -- don't fold away functions called in previous query
1384
$_$;
1385

    
1386

    
1387
--
1388
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1389
--
1390

    
1391
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1392
idempotent
1393
';
1394

    
1395

    
1396
--
1397
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1398
--
1399

    
1400
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1401
    LANGUAGE sql
1402
    AS $_$
1403
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1404
included in the debug SQL */
1405
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1406
$_$;
1407

    
1408

    
1409
--
1410
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1411
--
1412

    
1413
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1414
    LANGUAGE sql
1415
    AS $_$
1416
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1417
||util._if($3, $$ CASCADE$$, ''::text))
1418
$_$;
1419

    
1420

    
1421
--
1422
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1423
--
1424

    
1425
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1426
idempotent
1427
';
1428

    
1429

    
1430
--
1431
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1432
--
1433

    
1434
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1435
    LANGUAGE sql
1436
    AS $_$
1437
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1438
$_$;
1439

    
1440

    
1441
--
1442
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1443
--
1444

    
1445
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1446
    LANGUAGE sql
1447
    AS $_$
1448
SELECT util.debug_print_func_call(util.quote_func_call(
1449
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1450
util.quote_typed($3)))
1451
;
1452
SELECT util.drop_relation(relation, $3)
1453
FROM util.show_relations_like($1, $2) relation
1454
;
1455
SELECT NULL::void; -- don't fold away functions called in previous query
1456
$_$;
1457

    
1458

    
1459
--
1460
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1461
--
1462

    
1463
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1464
    LANGUAGE sql
1465
    AS $_$
1466
SELECT util.drop_relation('TABLE', $1, $2)
1467
$_$;
1468

    
1469

    
1470
--
1471
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1472
--
1473

    
1474
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1475
idempotent
1476
';
1477

    
1478

    
1479
--
1480
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1481
--
1482

    
1483
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1484
    LANGUAGE sql
1485
    AS $_$
1486
SELECT util.drop_relation('VIEW', $1, $2)
1487
$_$;
1488

    
1489

    
1490
--
1491
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1492
--
1493

    
1494
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1495
idempotent
1496
';
1497

    
1498

    
1499
--
1500
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1501
--
1502

    
1503
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1504
    LANGUAGE sql IMMUTABLE
1505
    AS $_$
1506
SELECT util.array_fill($1, 0)
1507
$_$;
1508

    
1509

    
1510
--
1511
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1512
--
1513

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

    
1518

    
1519
--
1520
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1521
--
1522

    
1523
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1524
    LANGUAGE sql IMMUTABLE
1525
    AS $_$
1526
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1527
$_$;
1528

    
1529

    
1530
--
1531
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1532
--
1533

    
1534
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1535
    LANGUAGE sql IMMUTABLE
1536
    AS $_$
1537
SELECT regexp_replace($2, '("?)$', $1||'\1')
1538
$_$;
1539

    
1540

    
1541
--
1542
-- Name: eval(text[]); Type: FUNCTION; Schema: util; Owner: -
1543
--
1544

    
1545
CREATE FUNCTION eval(queries text[]) RETURNS void
1546
    LANGUAGE sql
1547
    AS $_$
1548
SELECT util.eval(query) FROM unnest($1) query;
1549
SELECT NULL::void; -- don't fold away functions called in previous query
1550
$_$;
1551

    
1552

    
1553
--
1554
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1555
--
1556

    
1557
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1558
    LANGUAGE plpgsql
1559
    AS $$
1560
BEGIN
1561
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1562
	EXECUTE sql;
1563
END;
1564
$$;
1565

    
1566

    
1567
--
1568
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1569
--
1570

    
1571
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1572
    LANGUAGE plpgsql
1573
    AS $$
1574
BEGIN
1575
	PERFORM util.debug_print_sql(sql);
1576
	RETURN QUERY EXECUTE sql;
1577
END;
1578
$$;
1579

    
1580

    
1581
--
1582
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1583
--
1584

    
1585
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1586
col_type_null (*required*): NULL::col_type
1587
';
1588

    
1589

    
1590
--
1591
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1592
--
1593

    
1594
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1595
    LANGUAGE plpgsql
1596
    AS $$
1597
BEGIN
1598
	PERFORM util.debug_print_sql(sql);
1599
	RETURN QUERY EXECUTE sql;
1600
END;
1601
$$;
1602

    
1603

    
1604
--
1605
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1606
--
1607

    
1608
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1609
    LANGUAGE plpgsql
1610
    AS $$
1611
BEGIN
1612
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1613
	RETURN QUERY EXECUTE sql;
1614
END;
1615
$$;
1616

    
1617

    
1618
--
1619
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1620
--
1621

    
1622
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1623
    LANGUAGE plpgsql STABLE
1624
    AS $$
1625
DECLARE
1626
	ret_val ret_type_null%TYPE;
1627
BEGIN
1628
	PERFORM util.debug_print_sql(sql);
1629
	EXECUTE sql INTO STRICT ret_val;
1630
	RETURN ret_val;
1631
END;
1632
$$;
1633

    
1634

    
1635
--
1636
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1637
--
1638

    
1639
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1640
ret_type_null: NULL::ret_type
1641
';
1642

    
1643

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

    
1648
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1649
    LANGUAGE sql
1650
    AS $_$
1651
SELECT util.eval2val($$SELECT $$||$1, $2)
1652
$_$;
1653

    
1654

    
1655
--
1656
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1657
--
1658

    
1659
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1660
ret_type_null: NULL::ret_type
1661
';
1662

    
1663

    
1664
--
1665
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1666
--
1667

    
1668
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1669
    LANGUAGE sql
1670
    AS $_$
1671
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1672
$_$;
1673

    
1674

    
1675
--
1676
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1677
--
1678

    
1679
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1680
sql: can be NULL, which will be passed through
1681
ret_type_null: NULL::ret_type
1682
';
1683

    
1684

    
1685
--
1686
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1687
--
1688

    
1689
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1690
    LANGUAGE sql STABLE
1691
    AS $_$
1692
SELECT col_name
1693
FROM unnest($2) s (col_name)
1694
WHERE util.col_exists(($1, col_name))
1695
$_$;
1696

    
1697

    
1698
--
1699
-- Name: explain(text); Type: FUNCTION; Schema: util; Owner: -
1700
--
1701

    
1702
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1703
    LANGUAGE sql
1704
    SET client_min_messages TO 'error'
1705
    AS $_$
1706
/* `client_min_messages = ERROR`: EXPLAIN apparently runs IMMUTABLE functions in
1707
the query, so this prevents displaying any log messages printed by them */
1708
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1709
$_$;
1710

    
1711

    
1712
--
1713
-- Name: explain2notice(text); Type: FUNCTION; Schema: util; Owner: -
1714
--
1715

    
1716
CREATE FUNCTION explain2notice(sql text) RETURNS void
1717
    LANGUAGE sql
1718
    AS $_$
1719
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1720
$_$;
1721

    
1722

    
1723
--
1724
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1725
--
1726

    
1727
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1728
    LANGUAGE sql
1729
    AS $_$
1730
-- newline before and after to visually separate it from other debug info
1731
SELECT COALESCE($$
1732
EXPLAIN:
1733
$$||util.fold_explain_msg(util.explain2str($1))||$$
1734
$$, '')
1735
$_$;
1736

    
1737

    
1738
--
1739
-- Name: explain2notice_msg_if_can(text); Type: FUNCTION; Schema: util; Owner: -
1740
--
1741

    
1742
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1743
    LANGUAGE plpgsql
1744
    AS $$
1745
BEGIN
1746
	RETURN util.explain2notice_msg(sql);
1747
EXCEPTION
1748
WHEN   syntax_error
1749
	OR invalid_cursor_definition -- "cannot open multi-query plan as cursor"
1750
	THEN RETURN NULL; -- non-explainable query
1751
	/* don't use util.is_explainable() because the list provided by Postgres
1752
	(http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691)
1753
	excludes some query types that are in fact EXPLAIN-able */
1754
END;
1755
$$;
1756

    
1757

    
1758
--
1759
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1760
--
1761

    
1762
CREATE FUNCTION explain2str(sql text) RETURNS text
1763
    LANGUAGE sql
1764
    AS $_$
1765
SELECT util.join_strs(explain, $$
1766
$$) FROM util.explain($1)
1767
$_$;
1768

    
1769

    
1770
SET default_tablespace = '';
1771

    
1772
SET default_with_oids = false;
1773

    
1774
--
1775
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1776
--
1777

    
1778
CREATE TABLE explain (
1779
    line text NOT NULL
1780
);
1781

    
1782

    
1783
--
1784
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1785
--
1786

    
1787
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1788
    LANGUAGE sql
1789
    AS $_$
1790
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1791
$$||quote_nullable($1)||$$
1792
)$$)
1793
$_$;
1794

    
1795

    
1796
--
1797
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1798
--
1799

    
1800
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1801
usage:
1802
PERFORM util.explain2table($$
1803
query
1804
$$);
1805
';
1806

    
1807

    
1808
--
1809
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1810
--
1811

    
1812
CREATE FUNCTION first_word(str text) RETURNS text
1813
    LANGUAGE sql IMMUTABLE
1814
    AS $_$
1815
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1816
$_$;
1817

    
1818

    
1819
--
1820
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1821
--
1822

    
1823
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1824
    LANGUAGE sql IMMUTABLE
1825
    AS $_$
1826
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1827
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1828
) END
1829
$_$;
1830

    
1831

    
1832
--
1833
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1834
--
1835

    
1836
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1837
ensures that an array will always have proper non-NULL dimensions
1838
';
1839

    
1840

    
1841
--
1842
-- Name: fold_explain_msg(text); Type: FUNCTION; Schema: util; Owner: -
1843
--
1844

    
1845
CREATE FUNCTION fold_explain_msg(explain text) RETURNS text
1846
    LANGUAGE sql IMMUTABLE
1847
    AS $_$
1848
SELECT (CASE WHEN util.first_word($1) = 'Result' THEN NULL ELSE $1 END)
1849
$_$;
1850

    
1851

    
1852
--
1853
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1854
--
1855

    
1856
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1857
    LANGUAGE plpgsql STRICT
1858
    AS $_$
1859
DECLARE
1860
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1861
$$||query;
1862
BEGIN
1863
	EXECUTE mk_view;
1864
EXCEPTION
1865
WHEN invalid_table_definition THEN
1866
	IF SQLERRM = 'cannot drop columns from view'
1867
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1868
	THEN
1869
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1870
		EXECUTE mk_view;
1871
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1872
	END IF;
1873
END;
1874
$_$;
1875

    
1876

    
1877
--
1878
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1879
--
1880

    
1881
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1882
idempotent
1883
';
1884

    
1885

    
1886
--
1887
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1888
--
1889

    
1890
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1891
    LANGUAGE sql STABLE
1892
    AS $_$
1893
SELECT util.eval2val(
1894
$$SELECT NOT EXISTS( -- there is no row that is != 1
1895
	SELECT NULL
1896
	FROM $$||$1||$$
1897
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1898
	LIMIT 1
1899
)
1900
$$, NULL::boolean)
1901
$_$;
1902

    
1903

    
1904
--
1905
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1906
--
1907

    
1908
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1909
    LANGUAGE sql STABLE
1910
    AS $_$
1911
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1912
$_$;
1913

    
1914

    
1915
--
1916
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1917
--
1918

    
1919
CREATE FUNCTION grants_users() RETURNS SETOF text
1920
    LANGUAGE sql IMMUTABLE
1921
    AS $$
1922
VALUES ('bien_read'), ('public_')
1923
$$;
1924

    
1925

    
1926
--
1927
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1928
--
1929

    
1930
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1931
    LANGUAGE sql IMMUTABLE
1932
    AS $_$
1933
SELECT substring($2 for length($1)) = $1
1934
$_$;
1935

    
1936

    
1937
--
1938
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1939
--
1940

    
1941
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1942
    LANGUAGE sql STABLE
1943
    AS $_$
1944
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1945
$_$;
1946

    
1947

    
1948
--
1949
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1950
--
1951

    
1952
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1953
    LANGUAGE sql IMMUTABLE
1954
    AS $_$
1955
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1956
$_$;
1957

    
1958

    
1959
--
1960
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1961
--
1962

    
1963
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1964
avoids repeating the same value for each key
1965
';
1966

    
1967

    
1968
--
1969
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1970
--
1971

    
1972
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1973
    LANGUAGE sql IMMUTABLE
1974
    AS $_$
1975
SELECT COALESCE($1, $2)
1976
$_$;
1977

    
1978

    
1979
--
1980
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1981
--
1982

    
1983
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1984
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1985
';
1986

    
1987

    
1988
--
1989
-- Name: in_reverse(anyarray); Type: FUNCTION; Schema: util; Owner: -
1990
--
1991

    
1992
CREATE FUNCTION in_reverse("array" anyarray) RETURNS SETOF anyelement
1993
    LANGUAGE sql IMMUTABLE
1994
    AS $_$
1995
SELECT elem FROM unnest($1) elem ORDER BY row_number() OVER () DESC
1996
$_$;
1997

    
1998

    
1999
--
2000
-- Name: inherit(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
2001
--
2002

    
2003
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
2004
    LANGUAGE sql
2005
    AS $_$
2006
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
2007
$_$;
2008

    
2009

    
2010
--
2011
-- Name: is_castable(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2012
--
2013

    
2014
CREATE FUNCTION is_castable(value text, ret_type_null anyelement) RETURNS boolean
2015
    LANGUAGE plpgsql IMMUTABLE
2016
    AS $$
2017
BEGIN
2018
	PERFORM util.cast(value, ret_type_null);
2019
	-- must happen *after* cast check, because NULL is not valid for some types
2020
	IF value IS NULL THEN RETURN NULL; END IF; -- pass NULL through
2021
	RETURN true;
2022
EXCEPTION
2023
WHEN   data_exception
2024
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
2025
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
2026
	THEN
2027
	RETURN false;
2028
END;
2029
$$;
2030

    
2031

    
2032
--
2033
-- Name: FUNCTION is_castable(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
2034
--
2035

    
2036
COMMENT ON FUNCTION is_castable(value text, ret_type_null anyelement) IS '
2037
passes NULL through. however, if NULL is not valid for the type, false will be
2038
returned instead.
2039

    
2040
ret_type_null: NULL::ret_type
2041
';
2042

    
2043

    
2044
--
2045
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
2046
--
2047

    
2048
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
2049
    LANGUAGE sql STABLE
2050
    AS $_$
2051
SELECT COALESCE(util.col_comment($1) LIKE '
2052
constant
2053
%', false)
2054
$_$;
2055

    
2056

    
2057
--
2058
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2059
--
2060

    
2061
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
2062
    LANGUAGE sql IMMUTABLE
2063
    AS $_$
2064
SELECT util.array_length($1) = 0
2065
$_$;
2066

    
2067

    
2068
--
2069
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
2070
--
2071

    
2072
CREATE FUNCTION is_explain(sql text) RETURNS boolean
2073
    LANGUAGE sql IMMUTABLE
2074
    AS $_$
2075
SELECT upper(util.first_word($1)) = 'EXPLAIN'
2076
$_$;
2077

    
2078

    
2079
--
2080
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
2081
--
2082

    
2083
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
2084
    LANGUAGE sql IMMUTABLE
2085
    AS $_$
2086
SELECT upper(util.first_word($1)) = ANY(
2087
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
2088
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
2089
)
2090
$_$;
2091

    
2092

    
2093
--
2094
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2095
--
2096

    
2097
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
2098
    LANGUAGE sql IMMUTABLE
2099
    AS $_$
2100
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
2101
$_$;
2102

    
2103

    
2104
--
2105
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
2106
--
2107

    
2108
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
2109
    LANGUAGE sql IMMUTABLE
2110
    AS $_$
2111
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
2112
$_$;
2113

    
2114

    
2115
--
2116
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
2117
--
2118

    
2119
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
2120
    LANGUAGE sql IMMUTABLE
2121
    AS $_$
2122
SELECT upper(util.first_word($1)) = 'SET'
2123
$_$;
2124

    
2125

    
2126
--
2127
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
2128
--
2129

    
2130
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
2131
    LANGUAGE sql STABLE
2132
    AS $_$
2133
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
2134
$_$;
2135

    
2136

    
2137
--
2138
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
2139
--
2140

    
2141
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
2142
    LANGUAGE sql STABLE
2143
    AS $_$
2144
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
2145
$_$;
2146

    
2147

    
2148
--
2149
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
2150
--
2151

    
2152
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
2153
    LANGUAGE sql IMMUTABLE STRICT
2154
    AS $_$
2155
SELECT $1 || $3 || $2
2156
$_$;
2157

    
2158

    
2159
--
2160
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
2161
--
2162

    
2163
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
2164
must be declared STRICT to use the special handling of STRICT aggregating functions
2165
';
2166

    
2167

    
2168
--
2169
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
2170
--
2171

    
2172
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
2173
    LANGUAGE sql IMMUTABLE
2174
    AS $_$
2175
SELECT $1 -- compare on the entire value
2176
$_$;
2177

    
2178

    
2179
--
2180
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
2181
--
2182

    
2183
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
2184
    LANGUAGE sql IMMUTABLE
2185
    AS $_$
2186
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
2187
$_$;
2188

    
2189

    
2190
--
2191
-- Name: loop_ignore_errors(text, text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2192
--
2193

    
2194
CREATE FUNCTION loop_ignore_errors(iter_sql text, loop_body_sql text, loop_type_null anyelement DEFAULT NULL::text) RETURNS void
2195
    LANGUAGE plpgsql
2196
    AS $$
2197
DECLARE
2198
	errors_ct integer = 0;
2199
	loop_var loop_type_null%TYPE;
2200
BEGIN
2201
	FOR loop_var IN SELECT * FROM util.eval2set(iter_sql, loop_type_null)
2202
	LOOP
2203
		BEGIN
2204
			EXECUTE loop_body_sql USING loop_var;
2205
		EXCEPTION
2206
		WHEN OTHERS THEN
2207
			errors_ct = errors_ct+1;
2208
			PERFORM util.raise_error_warning(SQLERRM);
2209
		END;
2210
	END LOOP;
2211
	IF errors_ct > 0 THEN
2212
		-- can't raise exception because this would roll back the transaction
2213
		PERFORM util.raise_error_warning('there were '||errors_ct
2214
			||' errors: see the WARNINGs for details');
2215
	END IF;
2216
END;
2217
$$;
2218

    
2219

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

    
2224
CREATE FUNCTION ltrim_nl(str text) RETURNS text
2225
    LANGUAGE sql IMMUTABLE
2226
    AS $_$
2227
SELECT ltrim($1, $$
2228
$$)
2229
$_$;
2230

    
2231

    
2232
--
2233
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2234
--
2235

    
2236
CREATE FUNCTION map_filter_insert() RETURNS trigger
2237
    LANGUAGE plpgsql
2238
    AS $$
2239
BEGIN
2240
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2241
	RETURN new;
2242
END;
2243
$$;
2244

    
2245

    
2246
--
2247
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2248
--
2249

    
2250
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2251
    LANGUAGE plpgsql STABLE STRICT
2252
    AS $_$
2253
DECLARE
2254
    value text;
2255
BEGIN
2256
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2257
        INTO value USING key;
2258
    RETURN value;
2259
END;
2260
$_$;
2261

    
2262

    
2263
--
2264
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2265
--
2266

    
2267
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2268
    LANGUAGE sql IMMUTABLE
2269
    AS $_$
2270
SELECT util._map(util.nulls_map($1), $2)
2271
$_$;
2272

    
2273

    
2274
--
2275
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2276
--
2277

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

    
2281
[1] inlining of function calls, which is different from constant folding
2282
[2] _map()''s profiling query
2283
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2284
and map_nulls()''s profiling query
2285
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2286
both take ~920 ms.
2287
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.
2288
';
2289

    
2290

    
2291
--
2292
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2293
--
2294

    
2295
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2296
    LANGUAGE plpgsql STABLE STRICT
2297
    AS $_$
2298
BEGIN
2299
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2300
END;
2301
$_$;
2302

    
2303

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

    
2308
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2309
    LANGUAGE sql
2310
    AS $_$
2311
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2312
$$||util.ltrim_nl($2));
2313
-- make sure the created table has the correct estimated row count
2314
SELECT util.analyze_($1);
2315

    
2316
SELECT util.append_comment($1, '
2317
contents generated from:
2318
'||util.ltrim_nl(util.runnable_sql($2))||';
2319
');
2320
$_$;
2321

    
2322

    
2323
--
2324
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2325
--
2326

    
2327
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2328
idempotent
2329
';
2330

    
2331

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

    
2336
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2337
    LANGUAGE sql
2338
    AS $_$
2339
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2340
$_$;
2341

    
2342

    
2343
--
2344
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2345
--
2346

    
2347
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2348
idempotent
2349
';
2350

    
2351

    
2352
--
2353
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2354
--
2355

    
2356
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2357
    LANGUAGE sql
2358
    AS $_$
2359
SELECT util.create_if_not_exists($$
2360
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2361
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2362
||quote_literal($2)||$$;
2363
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2364
constant
2365
';
2366
$$)
2367
$_$;
2368

    
2369

    
2370
--
2371
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2372
--
2373

    
2374
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2375
idempotent
2376
';
2377

    
2378

    
2379
--
2380
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2381
--
2382

    
2383
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2384
    LANGUAGE plpgsql STRICT
2385
    AS $_$
2386
DECLARE
2387
    type regtype = util.typeof(expr, col.table_::text::regtype);
2388
    col_name_sql text = quote_ident(col.name);
2389
BEGIN
2390
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2391
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2392
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2393
$$||expr||$$;
2394
$$);
2395
END;
2396
$_$;
2397

    
2398

    
2399
--
2400
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2401
--
2402

    
2403
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2404
idempotent
2405
';
2406

    
2407

    
2408
--
2409
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2410
--
2411

    
2412
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
2413
    LANGUAGE sql IMMUTABLE
2414
    AS $_$
2415
SELECT
2416
$$SELECT
2417
$$||$3||$$
2418
FROM      $$||$1||$$ left_
2419
FULL JOIN $$||$2||$$ right_
2420
ON $$||$4||$$
2421
WHERE $$||$5||$$
2422
ORDER BY left_, right_
2423
$$
2424
$_$;
2425

    
2426

    
2427
--
2428
-- Name: mk_drop_from_create(text); Type: FUNCTION; Schema: util; Owner: -
2429
--
2430

    
2431
CREATE FUNCTION mk_drop_from_create(create_cmd text) RETURNS text
2432
    LANGUAGE sql IMMUTABLE
2433
    AS $_$
2434
SELECT $$DROP $$||(util.regexp_match($1,
2435
-- match first CREATE, *if* no DROP came before it
2436
'(?m)\A(?:^(?!DROP\y).*\n)*?^CREATE(?: OR REPLACE)? ((?:)??[[:upper:]]+ .*?)(?: AS(?: (?:SELECT\y.*)?)?)?$'
2437
	/* (?:)?? makes the surrounding () group non-greedy, so that (?: AS ?)?
2438
	works properly (due to nonstandard Postgres regexp behavior:
2439
	http://www.postgresql.org/docs/9.3/static/functions-matching.html#POSIX-MATCHING-RULES) */
2440
))[1]||$$;$$
2441
$_$;
2442

    
2443

    
2444
--
2445
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2446
--
2447

    
2448
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2449
    LANGUAGE sql
2450
    AS $_$
2451
-- keys()
2452
SELECT util.mk_keys_func($1, ARRAY(
2453
SELECT col FROM util.typed_cols($1) col
2454
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2455
));
2456

    
2457
-- values_()
2458
SELECT util.mk_keys_func($1, COALESCE(
2459
	NULLIF(ARRAY(
2460
	SELECT col FROM util.typed_cols($1) col
2461
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2462
	), ARRAY[]::util.col_cast[])
2463
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2464
, 'values_');
2465
$_$;
2466

    
2467

    
2468
--
2469
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2470
--
2471

    
2472
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2473
    LANGUAGE sql
2474
    AS $_$
2475
SELECT util.create_if_not_exists($$
2476
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2477
($$||util.mk_typed_cols_list($2)||$$);
2478
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2479
autogenerated
2480
';
2481
$$);
2482

    
2483
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2484
$_$;
2485

    
2486

    
2487
--
2488
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2489
--
2490

    
2491
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2492
    LANGUAGE sql
2493
    AS $_$
2494
SELECT util.create_if_not_exists($$
2495
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2496
||util.qual_name($1)||$$)
2497
  RETURNS $$||util.qual_name($2)||$$ AS
2498
$BODY1$
2499
SELECT ROW($$||
2500
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2501
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2502
$BODY1$
2503
  LANGUAGE sql IMMUTABLE
2504
  COST 100;
2505
$$);
2506
$_$;
2507

    
2508

    
2509
--
2510
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2511
--
2512

    
2513
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2514
    LANGUAGE sql
2515
    AS $_$
2516
SELECT util.create_if_not_exists($$
2517
CREATE TABLE $$||$1||$$
2518
(
2519
    LIKE util.map INCLUDING ALL
2520
);
2521

    
2522
CREATE TRIGGER map_filter_insert
2523
  BEFORE INSERT
2524
  ON $$||$1||$$
2525
  FOR EACH ROW
2526
  EXECUTE PROCEDURE util.map_filter_insert();
2527
$$)
2528
$_$;
2529

    
2530

    
2531
--
2532
-- Name: mk_not_null(text); Type: FUNCTION; Schema: util; Owner: -
2533
--
2534

    
2535
CREATE FUNCTION mk_not_null(text) RETURNS text
2536
    LANGUAGE sql IMMUTABLE
2537
    AS $_$
2538
SELECT COALESCE($1, '<NULL>')
2539
$_$;
2540

    
2541

    
2542
--
2543
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2544
--
2545

    
2546
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2547
    LANGUAGE sql IMMUTABLE
2548
    AS $_$
2549
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2550
util.qual_name((unnest).type), ''), '')
2551
FROM unnest($1)
2552
$_$;
2553

    
2554

    
2555
--
2556
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2557
--
2558

    
2559
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2560
    LANGUAGE sql IMMUTABLE
2561
    AS $_$
2562
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2563
$_$;
2564

    
2565

    
2566
--
2567
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2568
--
2569

    
2570
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2571
auto-appends util to the search_path to enable use of util operators
2572
';
2573

    
2574

    
2575
--
2576
-- Name: mk_set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2577
--
2578

    
2579
CREATE FUNCTION mk_set_comment(table_ regclass, comment text) RETURNS text
2580
    LANGUAGE sql STABLE
2581
    AS $_$
2582
SELECT COALESCE($$COMMENT ON $$||util.relation_type($1)||$$ $$||$1||$$ IS $$
2583
||quote_literal($2)/*pass NULL through*/||$$;$$, ''/*no comment*/)
2584
$_$;
2585

    
2586

    
2587
--
2588
-- Name: mk_set_relation_metadata(regclass); Type: FUNCTION; Schema: util; Owner: -
2589
--
2590

    
2591
CREATE FUNCTION mk_set_relation_metadata(relation regclass) RETURNS text
2592
    LANGUAGE sql STABLE
2593
    AS $_$
2594
SELECT util.show_grants_for($1)
2595
||util.show_set_comment($1)||$$
2596
$$
2597
$_$;
2598

    
2599

    
2600
--
2601
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2602
--
2603

    
2604
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2605
    LANGUAGE sql IMMUTABLE
2606
    AS $_$
2607
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2608
$_$;
2609

    
2610

    
2611
--
2612
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2613
--
2614

    
2615
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2616
    LANGUAGE sql IMMUTABLE
2617
    AS $_$
2618
/* debug_print_return_value() needed because this function is used with EXECUTE
2619
rather than util.eval() (in order to affect the calling function), so the
2620
search_path would not otherwise be printed */
2621
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2622
||$$ search_path TO $$||$1
2623
$_$;
2624

    
2625

    
2626
--
2627
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2628
--
2629

    
2630
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2631
    LANGUAGE sql
2632
    AS $_$
2633
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2634
$_$;
2635

    
2636

    
2637
--
2638
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2639
--
2640

    
2641
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2642
idempotent
2643
';
2644

    
2645

    
2646
--
2647
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2648
--
2649

    
2650
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2651
    LANGUAGE plpgsql STRICT
2652
    AS $_$
2653
DECLARE
2654
	view_qual_name text = util.qual_name(view_);
2655
BEGIN
2656
	EXECUTE $$
2657
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2658
  RETURNS SETOF $$||view_||$$ AS
2659
$BODY1$
2660
SELECT * FROM $$||view_qual_name||$$
2661
ORDER BY sort_col
2662
LIMIT $1 OFFSET $2
2663
$BODY1$
2664
  LANGUAGE sql STABLE
2665
  COST 100
2666
  ROWS 1000
2667
$$;
2668
	
2669
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2670
END;
2671
$_$;
2672

    
2673

    
2674
--
2675
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2676
--
2677

    
2678
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2679
    LANGUAGE plpgsql STRICT
2680
    AS $_$
2681
DECLARE
2682
	view_qual_name text = util.qual_name(view_);
2683
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2684
BEGIN
2685
	EXECUTE $$
2686
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2687
  RETURNS integer AS
2688
$BODY1$
2689
SELECT $$||quote_ident(row_num_col)||$$
2690
FROM $$||view_qual_name||$$
2691
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2692
LIMIT 1
2693
$BODY1$
2694
  LANGUAGE sql STABLE
2695
  COST 100;
2696
$$;
2697
	
2698
	EXECUTE $$
2699
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2700
  RETURNS SETOF $$||view_||$$ AS
2701
$BODY1$
2702
SELECT * FROM $$||view_qual_name||$$
2703
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2704
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2705
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2706
ORDER BY $$||quote_ident(row_num_col)||$$
2707
$BODY1$
2708
  LANGUAGE sql STABLE
2709
  COST 100
2710
  ROWS 1000
2711
$$;
2712
	
2713
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2714
END;
2715
$_$;
2716

    
2717

    
2718
--
2719
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2720
--
2721

    
2722
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2723
    LANGUAGE plpgsql STRICT
2724
    AS $_$
2725
DECLARE
2726
	view_qual_name text = util.qual_name(view_);
2727
BEGIN
2728
	EXECUTE $$
2729
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2730
  RETURNS SETOF $$||view_||$$
2731
  SET enable_sort TO 'off'
2732
  AS
2733
$BODY1$
2734
SELECT * FROM $$||view_qual_name||$$($2, $3)
2735
$BODY1$
2736
  LANGUAGE sql STABLE
2737
  COST 100
2738
  ROWS 1000
2739
;
2740
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2741
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2742
If you want to run EXPLAIN and get expanded output, use the regular subset
2743
function instead. (When a config param is set on a function, EXPLAIN produces
2744
just a function scan.)
2745
';
2746
$$;
2747
END;
2748
$_$;
2749

    
2750

    
2751
--
2752
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2753
--
2754

    
2755
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2756
creates subset function which turns off enable_sort
2757
';
2758

    
2759

    
2760
--
2761
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2762
--
2763

    
2764
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2765
    LANGUAGE sql IMMUTABLE
2766
    AS $_$
2767
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2768
util.qual_name((unnest).type), ', '), '')
2769
FROM unnest($1)
2770
$_$;
2771

    
2772

    
2773
--
2774
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2775
--
2776

    
2777
CREATE FUNCTION name(table_ regclass) RETURNS text
2778
    LANGUAGE sql STABLE
2779
    AS $_$
2780
SELECT relname::text FROM pg_class WHERE oid = $1
2781
$_$;
2782

    
2783

    
2784
--
2785
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2786
--
2787

    
2788
CREATE FUNCTION name(type regtype) RETURNS text
2789
    LANGUAGE sql STABLE
2790
    AS $_$
2791
SELECT typname::text FROM pg_type WHERE oid = $1
2792
$_$;
2793

    
2794

    
2795
--
2796
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2797
--
2798

    
2799
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2800
    LANGUAGE sql IMMUTABLE
2801
    AS $_$
2802
SELECT octet_length($1) >= util.namedatalen() - $2
2803
$_$;
2804

    
2805

    
2806
--
2807
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2808
--
2809

    
2810
CREATE FUNCTION namedatalen() RETURNS integer
2811
    LANGUAGE sql IMMUTABLE
2812
    AS $$
2813
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2814
$$;
2815

    
2816

    
2817
--
2818
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2819
--
2820

    
2821
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2822
    LANGUAGE sql IMMUTABLE
2823
    AS $_$
2824
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2825
$_$;
2826

    
2827

    
2828
--
2829
-- Name: not_null(anyelement); Type: FUNCTION; Schema: util; Owner: -
2830
--
2831

    
2832
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2833
    LANGUAGE sql IMMUTABLE
2834
    AS $_$
2835
SELECT $1 IS NOT NULL
2836
$_$;
2837

    
2838

    
2839
--
2840
-- Name: nulls_map(text[]); Type: FUNCTION; Schema: util; Owner: -
2841
--
2842

    
2843
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2844
    LANGUAGE sql IMMUTABLE
2845
    AS $_$
2846
SELECT util.hstore($1, NULL) || '*=>*'
2847
$_$;
2848

    
2849

    
2850
--
2851
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2852
--
2853

    
2854
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2855
for use with _map()
2856
';
2857

    
2858

    
2859
--
2860
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2861
--
2862

    
2863
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2864
    LANGUAGE sql IMMUTABLE
2865
    AS $_$
2866
SELECT $2 + COALESCE($1, 0)
2867
$_$;
2868

    
2869

    
2870
--
2871
-- Name: parent(regclass); Type: FUNCTION; Schema: util; Owner: -
2872
--
2873

    
2874
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2875
    LANGUAGE sql STABLE
2876
    AS $_$
2877
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2878
$_$;
2879

    
2880

    
2881
--
2882
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2883
--
2884

    
2885
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2886
    LANGUAGE sql
2887
    AS $_$
2888
SELECT util.eval($$INSERT INTO $$||$1||$$
2889
$$||util.ltrim_nl($2));
2890
-- make sure the created table has the correct estimated row count
2891
SELECT util.analyze_($1);
2892
$_$;
2893

    
2894

    
2895
--
2896
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2897
--
2898

    
2899
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2900
    LANGUAGE sql IMMUTABLE
2901
    AS $_$
2902
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2903
$_$;
2904

    
2905

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

    
2910
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2911
    LANGUAGE sql
2912
    AS $_$
2913
SELECT util.set_comment($1, concat($2, util.comment($1)))
2914
$_$;
2915

    
2916

    
2917
--
2918
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2919
--
2920

    
2921
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2922
comment: must start and end with a newline
2923
';
2924

    
2925

    
2926
--
2927
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2928
--
2929

    
2930
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2931
    LANGUAGE sql IMMUTABLE
2932
    AS $_$
2933
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2934
$_$;
2935

    
2936

    
2937
--
2938
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2939
--
2940

    
2941
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2942
    LANGUAGE sql STABLE
2943
    SET search_path TO pg_temp
2944
    AS $_$
2945
SELECT $1::text
2946
$_$;
2947

    
2948

    
2949
--
2950
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2951
--
2952

    
2953
CREATE FUNCTION qual_name(type regtype) RETURNS text
2954
    LANGUAGE sql STABLE
2955
    SET search_path TO pg_temp
2956
    AS $_$
2957
SELECT $1::text
2958
$_$;
2959

    
2960

    
2961
--
2962
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2963
--
2964

    
2965
COMMENT ON FUNCTION qual_name(type regtype) IS '
2966
a type''s schema-qualified name
2967
';
2968

    
2969

    
2970
--
2971
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2972
--
2973

    
2974
CREATE FUNCTION qual_name(type unknown) RETURNS text
2975
    LANGUAGE sql STABLE
2976
    AS $_$
2977
SELECT util.qual_name($1::text::regtype)
2978
$_$;
2979

    
2980

    
2981
--
2982
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2983
--
2984

    
2985
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2986
    LANGUAGE sql IMMUTABLE
2987
    AS $_$
2988
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2989
$_$;
2990

    
2991

    
2992
--
2993
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2994
--
2995

    
2996
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2997
    LANGUAGE sql IMMUTABLE
2998
    AS $_$
2999
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
3000
$_$;
3001

    
3002

    
3003
--
3004
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
3005
--
3006

    
3007
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
3008
    LANGUAGE sql IMMUTABLE
3009
    AS $_$
3010
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
3011
$_$;
3012

    
3013

    
3014
--
3015
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
3016
--
3017

    
3018
CREATE FUNCTION raise(type text, msg text) RETURNS void
3019
    LANGUAGE sql IMMUTABLE
3020
    AS $_X$
3021
SELECT util.eval($$
3022
CREATE OR REPLACE FUNCTION pg_temp.__raise()
3023
  RETURNS void AS
3024
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
3025
$__BODY1$
3026
BEGIN
3027
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
3028
END;
3029
$__BODY1$
3030
  LANGUAGE plpgsql IMMUTABLE
3031
  COST 100;
3032
$$, verbose_ := false);
3033

    
3034
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
3035
$_X$;
3036

    
3037

    
3038
--
3039
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
3040
--
3041

    
3042
COMMENT ON FUNCTION raise(type text, msg text) IS '
3043
type: a log level from
3044
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
3045
or a condition name from
3046
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
3047
';
3048

    
3049

    
3050
--
3051
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
3052
--
3053

    
3054
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
3055
    LANGUAGE sql IMMUTABLE
3056
    AS $_$
3057
SELECT util.raise('WARNING', 'ERROR:  '||$1)
3058
$_$;
3059

    
3060

    
3061
--
3062
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
3063
--
3064

    
3065
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
3066
    LANGUAGE plpgsql IMMUTABLE STRICT
3067
    AS $$
3068
BEGIN
3069
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
3070
END;
3071
$$;
3072

    
3073

    
3074
--
3075
-- Name: recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
3076
--
3077

    
3078
CREATE FUNCTION recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
3079
    LANGUAGE plpgsql
3080
    AS $_$
3081
DECLARE
3082
	PG_EXCEPTION_DETAIL text;
3083
	restore_views_info util.restore_views_info;
3084
BEGIN
3085
	restore_views_info = util.save_drop_views(users);
3086
	
3087
	-- trigger the dependent_objects_still_exist exception
3088
	PERFORM util.eval(COALESCE(util.mk_drop_from_create(cmd), '')||cmd);
3089
		-- *not* CASCADE; it must trigger an exception
3090
	
3091
	PERFORM util.restore_views(restore_views_info);
3092
EXCEPTION
3093
WHEN dependent_objects_still_exist THEN
3094
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
3095
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
3096
	users = array(SELECT * FROM util.regexp_matches_group(
3097
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on [[:lower:]]+ .*$'));
3098
		-- will be in forward dependency order
3099
	PERFORM util.debug_print_var('PG_EXCEPTION_DETAIL', PG_EXCEPTION_DETAIL);
3100
	PERFORM util.debug_print_var('users', users);
3101
	IF util.is_empty(users) THEN RAISE; END IF;
3102
	PERFORM util.recreate(cmd, users);
3103
END;
3104
$_$;
3105

    
3106

    
3107
--
3108
-- Name: FUNCTION recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
3109
--
3110

    
3111
COMMENT ON FUNCTION recreate(cmd text, users text[]) IS '
3112
the appropriate drop statement will be added automatically.
3113

    
3114
usage:
3115
SELECT util.recreate($$
3116
CREATE VIEW schema.main_view AS _;
3117

    
3118
-- manually restore views that need to be updated for the changes
3119
CREATE VIEW schema.dependent_view AS _;
3120
$$);
3121

    
3122
idempotent
3123

    
3124
users: not necessary to provide this because it will be autopopulated
3125
';
3126

    
3127

    
3128
--
3129
-- Name: recreate_view(regclass, text, text); Type: FUNCTION; Schema: util; Owner: -
3130
--
3131

    
3132
CREATE FUNCTION recreate_view(view_ regclass, view_query text DEFAULT NULL::text, dependent_view_changes text DEFAULT ''::text) RETURNS void
3133
    LANGUAGE sql
3134
    AS $_$
3135
SELECT util.recreate($$
3136
CREATE VIEW $$||$1||$$ AS 
3137
$$||COALESCE($2, pg_get_viewdef($1))||$$;
3138
$$||util.mk_set_relation_metadata($1)||$$
3139

    
3140
-- manually restore views that need to be updated for the changes
3141
$$||$3||$$
3142
$$);
3143
$_$;
3144

    
3145

    
3146
--
3147
-- Name: FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text); Type: COMMENT; Schema: util; Owner: -
3148
--
3149

    
3150
COMMENT ON FUNCTION recreate_view(view_ regclass, view_query text, dependent_view_changes text) IS '
3151
usage:
3152
SELECT util.recreate_view(''schema.main_view'', $$
3153
SELECT __
3154
$$, $$
3155
CREATE VIEW schema.dependent_view AS 
3156
__;
3157
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3158
$$);
3159

    
3160
if view has already been modified:
3161
SELECT util.recreate_view(''schema.main_view'', dependent_view_changes := $$
3162
CREATE VIEW schema.dependent_view AS 
3163
__;
3164
$$||util.mk_set_relation_metadata(''schema.dependent_view'')||$$
3165
$$);
3166

    
3167
idempotent
3168
';
3169

    
3170

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

    
3175
CREATE FUNCTION regexp_match(str text, re text) RETURNS text[]
3176
    LANGUAGE sql IMMUTABLE
3177
    AS $_$
3178
SELECT match FROM regexp_matches($1, $2) match LIMIT 1/*only 1st match*/
3179
$_$;
3180

    
3181

    
3182
--
3183
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3184
--
3185

    
3186
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
3187
    LANGUAGE sql IMMUTABLE
3188
    AS $_$
3189
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
3190
$_$;
3191

    
3192

    
3193
--
3194
-- Name: regexp_quote(text); Type: FUNCTION; Schema: util; Owner: -
3195
--
3196

    
3197
CREATE FUNCTION regexp_quote(str text) RETURNS text
3198
    LANGUAGE sql IMMUTABLE
3199
    AS $_$
3200
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
3201
$_$;
3202

    
3203

    
3204
--
3205
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
3206
--
3207

    
3208
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
3209
    LANGUAGE sql IMMUTABLE
3210
    AS $_$
3211
SELECT (CASE WHEN right($1, 1) = ')'
3212
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
3213
$_$;
3214

    
3215

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

    
3220
CREATE FUNCTION relation_exists(relation text) RETURNS boolean
3221
    LANGUAGE sql STABLE
3222
    AS $_$
3223
SELECT $1 IS NOT NULL AND util.is_castable($1, NULL::regclass)
3224
$_$;
3225

    
3226

    
3227
--
3228
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
3229
--
3230

    
3231
CREATE FUNCTION relation_type(relation regclass) RETURNS text
3232
    LANGUAGE sql STABLE
3233
    AS $_$
3234
SELECT util.relation_type(util.relation_type_char($1))
3235
$_$;
3236

    
3237

    
3238
--
3239
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
3240
--
3241

    
3242
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
3243
    LANGUAGE sql IMMUTABLE
3244
    AS $_$
3245
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
3246
$_$;
3247

    
3248

    
3249
--
3250
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
3251
--
3252

    
3253
CREATE FUNCTION relation_type(type regtype) RETURNS text
3254
    LANGUAGE sql IMMUTABLE
3255
    AS $$
3256
SELECT 'TYPE'::text
3257
$$;
3258

    
3259

    
3260
--
3261
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
3262
--
3263

    
3264
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
3265
    LANGUAGE sql STABLE
3266
    AS $_$
3267
SELECT relkind FROM pg_class WHERE oid = $1
3268
$_$;
3269

    
3270

    
3271
--
3272
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
3273
--
3274

    
3275
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
3276
    LANGUAGE sql
3277
    AS $_$
3278
/* can't have in_table/out_table inherit from *each other*, because inheritance
3279
also causes the rows of the parent table to be included in the child table.
3280
instead, they need to inherit from a common, empty table. */
3281
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
3282
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
3283
SELECT util.rm_freq(ARRAY[$4]); -- left/right_table don't have freq yet
3284
SELECT util.inherit($2, $4);
3285
SELECT util.inherit($3, $4);
3286

    
3287
SELECT util.rematerialize_query($1, $$
3288
SELECT * FROM util.diff(
3289
  $$||util.quote_typed($2)||$$
3290
, $$||util.quote_typed($3)||$$
3291
, NULL::$$||$4||$$)
3292
$$);
3293

    
3294
/* the table unfortunately cannot be *materialized* in human-readable form,
3295
because this would create column name collisions between the two sides */
3296
SELECT util.prepend_comment($1, '
3297
to view this table in human-readable form (with each side''s tuple column
3298
expanded to its component fields):
3299
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
3300

    
3301
to display NULL values that are extra or missing:
3302
SELECT * FROM '||$1||';
3303
');
3304
$_$;
3305

    
3306

    
3307
--
3308
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
3309
--
3310

    
3311
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
3312
type_table (*required*): table to create as the shared base type
3313
';
3314

    
3315

    
3316
--
3317
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
3318
--
3319

    
3320
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
3321
    LANGUAGE sql
3322
    AS $_$
3323
SELECT util.drop_table($1);
3324
SELECT util.materialize_query($1, $2);
3325
$_$;
3326

    
3327

    
3328
--
3329
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
3330
--
3331

    
3332
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
3333
idempotent, but repeats action each time
3334
';
3335

    
3336

    
3337
--
3338
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
3339
--
3340

    
3341
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
3342
    LANGUAGE sql
3343
    AS $_$
3344
SELECT util.drop_table($1);
3345
SELECT util.materialize_view($1, $2);
3346
$_$;
3347

    
3348

    
3349
--
3350
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
3351
--
3352

    
3353
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
3354
idempotent, but repeats action each time
3355
';
3356

    
3357

    
3358
--
3359
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
3360
--
3361

    
3362
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
3363
    LANGUAGE sql
3364
    AS $_$
3365
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
3366
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
3367
FROM util.col_names($1::text::regtype) f (name);
3368
SELECT NULL::void; -- don't fold away functions called in previous query
3369
$_$;
3370

    
3371

    
3372
--
3373
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
3374
--
3375

    
3376
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
3377
idempotent
3378
';
3379

    
3380

    
3381
--
3382
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3383
--
3384

    
3385
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
3386
    LANGUAGE sql
3387
    AS $_$
3388
/* use util.qual_name() instead of ::text so that the schema qualifier is always
3389
included in the debug SQL */
3390
SELECT util.rename_relation(util.qual_name($1), $2)
3391
$_$;
3392

    
3393

    
3394
--
3395
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
3396
--
3397

    
3398
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
3399
    LANGUAGE sql
3400
    AS $_$
3401
/* 'ALTER TABLE can be used with views too'
3402
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
3403
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
3404
||quote_ident($2))
3405
$_$;
3406

    
3407

    
3408
--
3409
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3410
--
3411

    
3412
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3413
idempotent
3414
';
3415

    
3416

    
3417
--
3418
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3419
--
3420

    
3421
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3422
    LANGUAGE sql IMMUTABLE
3423
    AS $_$
3424
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3425
$_$;
3426

    
3427

    
3428
--
3429
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3430
--
3431

    
3432
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3433
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 
3434
';
3435

    
3436

    
3437
--
3438
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3439
--
3440

    
3441
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3442
    LANGUAGE sql
3443
    AS $_$
3444
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3445
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3446
SELECT util.set_col_names($1, $2);
3447
$_$;
3448

    
3449

    
3450
--
3451
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3452
--
3453

    
3454
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3455
idempotent.
3456
alters the names table, so it will need to be repopulated after running this function.
3457
';
3458

    
3459

    
3460
--
3461
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3462
--
3463

    
3464
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3465
    LANGUAGE sql
3466
    AS $_$
3467
SELECT util.drop_table($1);
3468
SELECT util.mk_map_table($1);
3469
$_$;
3470

    
3471

    
3472
--
3473
-- Name: restore_views(restore_views_info); Type: FUNCTION; Schema: util; Owner: -
3474
--
3475

    
3476
CREATE FUNCTION restore_views(restore_views_info) RETURNS void
3477
    LANGUAGE sql
3478
    AS $_$
3479
SELECT util.debug_print_var('views', $1);
3480
SELECT util.create_if_not_exists((view_).def, (view_).path)
3481
	/* need to specify view name for manual existence check, in case view def
3482
	becomes invalid, which would produce nonstandard (uncatchable) exception */
3483
FROM unnest($1.views) view_; -- in forward dependency order
3484
	/* create_if_not_exists() rather than eval(), because cmd might manually
3485
	re-create a deleted dependent view, causing it to already exist */
3486
SELECT NULL::void; -- don't fold away functions called in previous query
3487
$_$;
3488

    
3489

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

    
3494
CREATE FUNCTION rm_freq(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS void
3495
    LANGUAGE sql
3496
    AS $_$
3497
SELECT util.drop_column($1, $2, force := true)
3498
$_$;
3499

    
3500

    
3501
--
3502
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3503
--
3504

    
3505
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3506
    LANGUAGE sql IMMUTABLE
3507
    AS $_$
3508
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3509
$_$;
3510

    
3511

    
3512
--
3513
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3514
--
3515

    
3516
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3517
    LANGUAGE sql IMMUTABLE
3518
    AS $_$
3519
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3520
ELSE util.mk_set_search_path(for_printing := true)||$$;
3521
$$ END)||$1
3522
$_$;
3523

    
3524

    
3525
--
3526
-- Name: save_drop_view(text); Type: FUNCTION; Schema: util; Owner: -
3527
--
3528

    
3529
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3530
    LANGUAGE plpgsql STRICT
3531
    AS $$
3532
DECLARE
3533
	result text = NULL;
3534
BEGIN
3535
	BEGIN
3536
		result = util.show_create_view(view_, replace := false);
3537
			/* replace: no `OR REPLACE` because that causes nonuniform errors
3538
			(eg. invalid_table_definition), instead of the standard
3539
			duplicate_table exception caught by util.create_if_not_exists() */
3540
		PERFORM util.drop_view(view_);
3541
	EXCEPTION
3542
		WHEN undefined_table THEN NULL;
3543
	END;
3544
	RETURN result;
3545
END;
3546
$$;
3547

    
3548

    
3549
--
3550
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3551
--
3552

    
3553
CREATE FUNCTION save_drop_views(views text[]) RETURNS restore_views_info
3554
    LANGUAGE sql
3555
    AS $_$
3556
SELECT ROW(/*return in forward dependency order*/util.array_reverse(array(
3557
SELECT (view_, util.save_drop_view(view_))::util.db_item
3558
FROM unnest(/*drop in reverse dependency order*/util.array_reverse($1)) view_
3559
)))::util.restore_views_info
3560
$_$;
3561

    
3562

    
3563
--
3564
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3565
--
3566

    
3567
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3568
    LANGUAGE sql STABLE
3569
    AS $_$
3570
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3571
$_$;
3572

    
3573

    
3574
--
3575
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3576
--
3577

    
3578
CREATE FUNCTION schema(table_ regclass) RETURNS text
3579
    LANGUAGE sql STABLE
3580
    AS $_$
3581
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3582
$_$;
3583

    
3584

    
3585
--
3586
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3587
--
3588

    
3589
CREATE FUNCTION schema(type regtype) RETURNS text
3590
    LANGUAGE sql STABLE
3591
    AS $_$
3592
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3593
$_$;
3594

    
3595

    
3596
--
3597
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3598
--
3599

    
3600
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3601
    LANGUAGE sql STABLE
3602
    AS $_$
3603
SELECT util.schema(pg_typeof($1))
3604
$_$;
3605

    
3606

    
3607
--
3608
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3609
--
3610

    
3611
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3612
    LANGUAGE sql STABLE
3613
    AS $_$
3614
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3615
$_$;
3616

    
3617

    
3618
--
3619
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3620
--
3621

    
3622
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3623
a schema bundle is a group of schemas with a common prefix
3624
';
3625

    
3626

    
3627
--
3628
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3629
--
3630

    
3631
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3632
    LANGUAGE sql
3633
    AS $_$
3634
SELECT util.schema_rename(old_schema,
3635
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3636
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3637
SELECT NULL::void; -- don't fold away functions called in previous query
3638
$_$;
3639

    
3640

    
3641
--
3642
-- Name: schema_bundle_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3643
--
3644

    
3645
CREATE FUNCTION schema_bundle_replace(replace text, with_ text) RETURNS void
3646
    LANGUAGE plpgsql
3647
    AS $$
3648
BEGIN
3649
	-- don't schema_bundle_rm() the schema_bundle to keep!
3650
	IF replace = with_ THEN RETURN; END IF;
3651
	
3652
	PERFORM util.schema_bundle_rm(replace);
3653
	PERFORM util.schema_bundle_rename(with_, replace);
3654
END;
3655
$$;
3656

    
3657

    
3658
--
3659
-- Name: schema_bundle_rm(text); Type: FUNCTION; Schema: util; Owner: -
3660
--
3661

    
3662
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3663
    LANGUAGE sql
3664
    AS $_$
3665
SELECT util.schema_rm(schema)
3666
FROM util.schema_bundle_get_schemas($1) f (schema);
3667
SELECT NULL::void; -- don't fold away functions called in previous query
3668
$_$;
3669

    
3670

    
3671
--
3672
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3673
--
3674

    
3675
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3676
    LANGUAGE sql STABLE
3677
    AS $_$
3678
SELECT quote_ident(util.schema($1))
3679
$_$;
3680

    
3681

    
3682
--
3683
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3684
--
3685

    
3686
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3687
    LANGUAGE sql IMMUTABLE
3688
    AS $_$
3689
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3690
$_$;
3691

    
3692

    
3693
--
3694
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3695
--
3696

    
3697
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3698
    LANGUAGE sql STABLE
3699
    AS $_$
3700
SELECT oid FROM pg_namespace WHERE nspname = $1
3701
$_$;
3702

    
3703

    
3704
--
3705
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3706
--
3707

    
3708
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3709
    LANGUAGE sql IMMUTABLE
3710
    AS $_$
3711
SELECT util.schema_regexp(schema_anchor := $1)
3712
$_$;
3713

    
3714

    
3715
--
3716
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3717
--
3718

    
3719
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3720
    LANGUAGE sql IMMUTABLE
3721
    AS $_$
3722
SELECT util.str_equality_regexp(util.schema($1))
3723
$_$;
3724

    
3725

    
3726
--
3727
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3728
--
3729

    
3730
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3731
    LANGUAGE sql
3732
    AS $_$
3733
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3734
$_$;
3735

    
3736

    
3737
--
3738
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3739
--
3740

    
3741
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3742
    LANGUAGE plpgsql
3743
    AS $$
3744
BEGIN
3745
	-- don't schema_rm() the schema to keep!
3746
	IF replace = with_ THEN RETURN; END IF;
3747
	
3748
	PERFORM util.schema_rm(replace);
3749
	PERFORM util.schema_rename(with_, replace);
3750
END;
3751
$$;
3752

    
3753

    
3754
--
3755
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3756
--
3757

    
3758
CREATE FUNCTION schema_rm(schema text) RETURNS void
3759
    LANGUAGE sql
3760
    AS $_$
3761
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3762
$_$;
3763

    
3764

    
3765
--
3766
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3767
--
3768

    
3769
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3770
    LANGUAGE sql
3771
    AS $_$
3772
SELECT util.eval(
3773
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3774
$_$;
3775

    
3776

    
3777
--
3778
-- Name: seq__create(text, integer); Type: FUNCTION; Schema: util; Owner: -
3779
--
3780

    
3781
CREATE FUNCTION seq__create(seq text, start integer DEFAULT 0) RETURNS void
3782
    LANGUAGE sql
3783
    AS $_$
3784
SELECT util.create_if_not_exists($$CREATE SEQUENCE $$||$1||$$ MINVALUE $$||$2,
3785
$1)
3786
$_$;
3787

    
3788

    
3789
--
3790
-- Name: FUNCTION seq__create(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
3791
--
3792

    
3793
COMMENT ON FUNCTION seq__create(seq text, start integer) IS '
3794
idempotent
3795
';
3796

    
3797

    
3798
--
3799
-- Name: seq__reset(text, integer); Type: FUNCTION; Schema: util; Owner: -
3800
--
3801

    
3802
CREATE FUNCTION seq__reset(seq text, start integer DEFAULT 0) RETURNS void
3803
    LANGUAGE sql
3804
    AS $_$
3805
SELECT util.seq__create($1, $2);
3806
SELECT util.eval($$ALTER SEQUENCE $$||$1||$$ RESTART$$);
3807
$_$;
3808

    
3809

    
3810
--
3811
-- Name: FUNCTION seq__reset(seq text, start integer); Type: COMMENT; Schema: util; Owner: -
3812
--
3813

    
3814
COMMENT ON FUNCTION seq__reset(seq text, start integer) IS '
3815
creates sequence if doesn''t exist
3816

    
3817
idempotent
3818

    
3819
start: *note*: only used if sequence doesn''t exist
3820
';
3821

    
3822

    
3823
--
3824
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3825
--
3826

    
3827
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3828
    LANGUAGE plpgsql STRICT
3829
    AS $_$
3830
DECLARE
3831
    old text[] = ARRAY(SELECT util.col_names(table_));
3832
    new text[] = ARRAY(SELECT util.map_values(names));
3833
BEGIN
3834
    old = old[1:array_length(new, 1)]; -- truncate to same length
3835
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3836
||$$ TO $$||quote_ident(value))
3837
    FROM each(hstore(old, new))
3838
    WHERE value != key -- not same name
3839
    ;
3840
END;
3841
$_$;
3842

    
3843

    
3844
--
3845
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3846
--
3847

    
3848
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3849
idempotent
3850
';
3851

    
3852

    
3853
--
3854
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3855
--
3856

    
3857
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3858
    LANGUAGE plpgsql STRICT
3859
    AS $_$
3860
DECLARE
3861
	row_ util.map;
3862
BEGIN
3863
	-- rename any metadata cols rather than re-adding them with new names
3864
	BEGIN
3865
		PERFORM util.set_col_names(table_, names);
3866
	EXCEPTION
3867
		WHEN array_subscript_error THEN -- selective suppress
3868
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3869
				-- metadata cols not yet added
3870
			ELSE RAISE;
3871
			END IF;
3872
	END;
3873
	
3874
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3875
	LOOP
3876
		PERFORM util.mk_const_col((table_, row_."to"),
3877
			substring(row_."from" from 2));
3878
	END LOOP;
3879
	
3880
	PERFORM util.set_col_names(table_, names);
3881
END;
3882
$_$;
3883

    
3884

    
3885
--
3886
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3887
--
3888

    
3889
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3890
idempotent.
3891
the metadata mappings must be *last* in the names table.
3892
';
3893

    
3894

    
3895
--
3896
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3897
--
3898

    
3899
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3900
    LANGUAGE sql
3901
    AS $_$
3902
SELECT util.eval(COALESCE(
3903
$$ALTER TABLE $$||$1||$$
3904
$$||(
3905
	SELECT
3906
	string_agg($$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3907
	||$$ USING $$||col_name_sql||$$::$$||target_type, $$
3908
, $$)
3909
	FROM
3910
	(
3911
		SELECT
3912
		  quote_ident(col_name) AS col_name_sql
3913
		, util.col_type(($1, col_name)) AS curr_type
3914
		, type AS target_type
3915
		FROM unnest($2)
3916
	) s
3917
	WHERE curr_type != target_type
3918
), ''))
3919
$_$;
3920

    
3921

    
3922
--
3923
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3924
--
3925

    
3926
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3927
idempotent
3928
';
3929

    
3930

    
3931
--
3932
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3933
--
3934

    
3935
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3936
    LANGUAGE sql
3937
    AS $_$
3938
SELECT util.eval(util.mk_set_comment($1, $2))
3939
$_$;
3940

    
3941

    
3942
--
3943
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3944
--
3945

    
3946
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3947
    LANGUAGE sql
3948
    AS $_$
3949
SELECT util.eval(util.mk_set_search_path($1, $2))
3950
$_$;
3951

    
3952

    
3953
--
3954
-- Name: show_create_view(regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
3955
--
3956

    
3957
CREATE FUNCTION show_create_view(view_ regclass, replace boolean DEFAULT true) RETURNS text
3958
    LANGUAGE sql STABLE
3959
    AS $_$
3960
SELECT $$CREATE$$||(CASE WHEN $2 THEN $$ OR REPLACE$$ ELSE '' END)||$$ VIEW $$
3961
||$1||$$ AS
3962
$$||pg_get_viewdef($1)/*no ; because pg_get_viewdef() includes one*/||$$
3963
$$||util.mk_set_relation_metadata($1)
3964
$_$;
3965

    
3966

    
3967
--
3968
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3969
--
3970

    
3971
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3972
    LANGUAGE sql STABLE
3973
    AS $_$
3974
SELECT string_agg(cmd, '')
3975
FROM
3976
(
3977
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3978
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3979
$$ ELSE '' END) AS cmd
3980
	FROM util.grants_users() f (user_)
3981
) s
3982
$_$;
3983

    
3984

    
3985
--
3986
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3987
--
3988

    
3989
CREATE FUNCTION show_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, types character[] DEFAULT ARRAY['c'::text, 'r'::text, 'v'::text]) RETURNS SETOF regclass
3990
    LANGUAGE sql STABLE
3991
    AS $_$
3992
SELECT oid FROM pg_class
3993
WHERE relkind = ANY($3) AND relname ~ $1
3994
AND util.schema_matches(util.schema(relnamespace), $2)
3995
ORDER BY relname
3996
$_$;
3997

    
3998

    
3999
--
4000
-- Name: show_set_comment(regclass); Type: FUNCTION; Schema: util; Owner: -
4001
--
4002

    
4003
CREATE FUNCTION show_set_comment(table_ regclass) RETURNS text
4004
    LANGUAGE sql STABLE
4005
    AS $_$
4006
SELECT util.mk_set_comment($1, util.comment($1))
4007
$_$;
4008

    
4009

    
4010
--
4011
-- Name: show_types_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4012
--
4013

    
4014
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
4015
    LANGUAGE sql STABLE
4016
    AS $_$
4017
SELECT oid
4018
FROM pg_type
4019
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
4020
ORDER BY typname
4021
$_$;
4022

    
4023

    
4024
--
4025
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
4026
--
4027

    
4028
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
4029
    LANGUAGE sql STABLE
4030
    AS $_$
4031
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
4032
$_$;
4033

    
4034

    
4035
--
4036
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
4037
--
4038

    
4039
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
4040
    LANGUAGE sql IMMUTABLE
4041
    AS $_$
4042
SELECT '^'||util.regexp_quote($1)||'$'
4043
$_$;
4044

    
4045

    
4046
--
4047
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
4048
--
4049

    
4050
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
4051
    LANGUAGE plpgsql STABLE STRICT
4052
    AS $_$
4053
DECLARE
4054
    hstore hstore;
4055
BEGIN
4056
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
4057
        table_||$$))$$ INTO STRICT hstore;
4058
    RETURN hstore;
4059
END;
4060
$_$;
4061

    
4062

    
4063
--
4064
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4065
--
4066

    
4067
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
4068
    LANGUAGE sql STABLE
4069
    AS $_$
4070
SELECT COUNT(*) > 0 FROM pg_constraint
4071
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
4072
$_$;
4073

    
4074

    
4075
--
4076
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4077
--
4078

    
4079
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
4080
gets whether a status flag is set by the presence of a table constraint
4081
';
4082

    
4083

    
4084
--
4085
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
4086
--
4087

    
4088
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
4089
    LANGUAGE sql
4090
    AS $_$
4091
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
4092
||quote_ident($2)||$$ CHECK (true)$$)
4093
$_$;
4094

    
4095

    
4096
--
4097
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
4098
--
4099

    
4100
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
4101
stores a status flag by the presence of a table constraint.
4102
idempotent.
4103
';
4104

    
4105

    
4106
--
4107
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
4108
--
4109

    
4110
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
4111
    LANGUAGE sql STABLE
4112
    AS $_$
4113
SELECT util.table_flag__get($1, 'nulls_mapped')
4114
$_$;
4115

    
4116

    
4117
--
4118
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4119
--
4120

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

    
4125

    
4126
--
4127
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
4128
--
4129

    
4130
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
4131
    LANGUAGE sql
4132
    AS $_$
4133
SELECT util.table_flag__set($1, 'nulls_mapped')
4134
$_$;
4135

    
4136

    
4137
--
4138
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4139
--
4140

    
4141
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
4142
sets that a table''s NULL-equivalent strings have been replaced with NULL.
4143
idempotent.
4144
';
4145

    
4146

    
4147
--
4148
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
4149
--
4150

    
4151
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
4152
    LANGUAGE sql
4153
    AS $_$
4154
-- save data before truncating main table
4155
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
4156

    
4157
-- repopulate main table w/ copies column
4158
SELECT util.truncate($1);
4159
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
4160
SELECT util.populate_table($1, $$
4161
SELECT (table_).*, copies
4162
FROM (
4163
	SELECT table_, COUNT(*) AS copies
4164
	FROM pg_temp.__copy table_
4165
	GROUP BY table_
4166
) s
4167
$$);
4168

    
4169
-- delete temp table so it doesn't stay around until end of connection
4170
SELECT util.drop_table('pg_temp.__copy');
4171
$_$;
4172

    
4173

    
4174
--
4175
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
4176
--
4177

    
4178
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
4179
    LANGUAGE plpgsql STRICT
4180
    AS $_$
4181
DECLARE
4182
    row record;
4183
BEGIN
4184
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
4185
    LOOP
4186
        IF row.global_name != row.name THEN
4187
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
4188
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
4189
        END IF;
4190
    END LOOP;
4191
END;
4192
$_$;
4193

    
4194

    
4195
--
4196
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4197
--
4198

    
4199
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
4200
idempotent
4201
';
4202

    
4203

    
4204
--
4205
-- Name: trim(regclass, regclass, boolean); Type: FUNCTION; Schema: util; Owner: -
4206
--
4207

    
4208
CREATE FUNCTION "trim"(table_ regclass, names regclass, force boolean DEFAULT true) RETURNS void
4209
    LANGUAGE sql
4210
    AS $_$
4211
SELECT util.drop_column(($1, col), $3) FROM util.added_cols($1, $2) f (col);
4212
SELECT NULL::void; -- don't fold away functions called in previous query
4213
$_$;
4214

    
4215

    
4216
--
4217
-- Name: FUNCTION "trim"(table_ regclass, names regclass, force boolean); Type: COMMENT; Schema: util; Owner: -
4218
--
4219

    
4220
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass, force boolean) IS '
4221
trims table_ to include only columns in the original data
4222

    
4223
by default, cascadingly drops dependent columns so that they don''t prevent
4224
trim() from succeeding. note that this requires the dependent columns to then be
4225
manually re-created.
4226

    
4227
idempotent
4228
';
4229

    
4230

    
4231
--
4232
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
4233
--
4234

    
4235
CREATE FUNCTION truncate(table_ regclass) RETURNS void
4236
    LANGUAGE plpgsql STRICT
4237
    AS $_$
4238
BEGIN
4239
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
4240
END;
4241
$_$;
4242

    
4243

    
4244
--
4245
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
4246
--
4247

    
4248
COMMENT ON FUNCTION truncate(table_ regclass) IS '
4249
idempotent
4250
';
4251

    
4252

    
4253
--
4254
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
4255
--
4256

    
4257
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
4258
    LANGUAGE sql IMMUTABLE
4259
    AS $_$
4260
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
4261
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
4262
$_$;
4263

    
4264

    
4265
--
4266
-- Name: try_cast(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
4267
--
4268

    
4269
CREATE FUNCTION try_cast(value text, ret_type_null anyelement) RETURNS anyelement
4270
    LANGUAGE plpgsql IMMUTABLE
4271
    AS $$
4272
BEGIN
4273
	/* need explicit cast because some types not implicitly-castable, and also
4274
	to make the cast happen inside the try block. (*implicit* casts to the
4275
	return type happen at the end of the function, outside any block.) */
4276
	RETURN util.cast(value, ret_type_null);
4277
EXCEPTION
4278
WHEN   data_exception
4279
	OR invalid_schema_name -- eg. 'pg_temp.__'::regclass
4280
	OR syntax_error_or_access_rule_violation -- eg. ::regclass
4281
	THEN
4282
	PERFORM util.raise('WARNING', SQLERRM);
4283
	RETURN NULL;
4284
END;
4285
$$;
4286

    
4287

    
4288
--
4289
-- Name: FUNCTION try_cast(value text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
4290
--
4291

    
4292
COMMENT ON FUNCTION try_cast(value text, ret_type_null anyelement) IS '
4293
ret_type_null: NULL::ret_type
4294
';
4295

    
4296

    
4297
--
4298
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
4299
--
4300

    
4301
CREATE FUNCTION try_create(sql text) RETURNS void
4302
    LANGUAGE plpgsql STRICT
4303
    AS $$
4304
BEGIN
4305
	PERFORM util.eval(sql);
4306
EXCEPTION
4307
WHEN   not_null_violation
4308
		/* trying to add NOT NULL column to parent table, which cascades to
4309
		child table whose values for the new column will be NULL */
4310
	OR wrong_object_type -- trying to alter a view's columns
4311
	OR undefined_column
4312
	OR duplicate_column
4313
THEN NULL;
4314
WHEN datatype_mismatch THEN
4315
	IF SQLERRM LIKE 'child table is missing column %' THEN NULL;
4316
	ELSE RAISE; -- rethrow
4317
	END IF;
4318
END;
4319
$$;
4320

    
4321

    
4322
--
4323
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
4324
--
4325

    
4326
COMMENT ON FUNCTION try_create(sql text) IS '
4327
idempotent
4328
';
4329

    
4330

    
4331
--
4332
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
4333
--
4334

    
4335
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
4336
    LANGUAGE sql
4337
    AS $_$
4338
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
4339
$_$;
4340

    
4341

    
4342
--
4343
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
4344
--
4345

    
4346
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
4347
idempotent
4348
';
4349

    
4350

    
4351
--
4352
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
4353
--
4354

    
4355
CREATE FUNCTION type_qual(value anyelement) RETURNS text
4356
    LANGUAGE sql IMMUTABLE
4357
    AS $_$
4358
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
4359
$_$;
4360

    
4361

    
4362
--
4363
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
4364
--
4365

    
4366
COMMENT ON FUNCTION type_qual(value anyelement) IS '
4367
a type''s NOT NULL qualifier
4368
';
4369

    
4370

    
4371
--
4372
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
4373
--
4374

    
4375
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
4376
    LANGUAGE sql STABLE
4377
    AS $_$
4378
SELECT (attname::text, atttypid)::util.col_cast
4379
FROM pg_attribute
4380
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
4381
ORDER BY attnum
4382
$_$;
4383

    
4384

    
4385
--
4386
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
4387
--
4388

    
4389
CREATE FUNCTION typeof(value anyelement) RETURNS text
4390
    LANGUAGE sql IMMUTABLE
4391
    AS $_$
4392
SELECT util.qual_name(pg_typeof($1))
4393
$_$;
4394

    
4395

    
4396
--
4397
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
4398
--
4399

    
4400
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
4401
    LANGUAGE plpgsql STABLE
4402
    AS $_$
4403
DECLARE
4404
    type regtype;
4405
BEGIN
4406
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
4407
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
4408
    RETURN type;
4409
END;
4410
$_$;
4411

    
4412

    
4413
--
4414
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
4415
--
4416

    
4417
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
4418
    LANGUAGE sql
4419
    AS $_$
4420
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
4421
$_$;
4422

    
4423

    
4424
--
4425
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
4426
--
4427

    
4428
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
4429
auto-appends util to the search_path to enable use of util operators
4430
';
4431

    
4432

    
4433
--
4434
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
4435
--
4436

    
4437
CREATE AGGREGATE all_same(anyelement) (
4438
    SFUNC = all_same_transform,
4439
    STYPE = anyarray,
4440
    FINALFUNC = all_same_final
4441
);
4442

    
4443

    
4444
--
4445
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
4446
--
4447

    
4448
COMMENT ON AGGREGATE all_same(anyelement) IS '
4449
includes NULLs in comparison
4450
';
4451

    
4452

    
4453
--
4454
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
4455
--
4456

    
4457
CREATE AGGREGATE join_strs(text, text) (
4458
    SFUNC = join_strs_transform,
4459
    STYPE = text
4460
);
4461

    
4462

    
4463
--
4464
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
4465
--
4466

    
4467
CREATE OPERATOR %== (
4468
    PROCEDURE = "%==",
4469
    LEFTARG = anyelement,
4470
    RIGHTARG = anyelement
4471
);
4472

    
4473

    
4474
--
4475
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
4476
--
4477

    
4478
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
4479
returns whether the map-keys of the compared values are the same
4480
(mnemonic: % is the Perl symbol for a hash map)
4481

    
4482
should be overridden for types that store both keys and values
4483

    
4484
used in a FULL JOIN to select which columns to join on
4485
';
4486

    
4487

    
4488
--
4489
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
4490
--
4491

    
4492
CREATE OPERATOR -> (
4493
    PROCEDURE = map_get,
4494
    LEFTARG = regclass,
4495
    RIGHTARG = text
4496
);
4497

    
4498

    
4499
--
4500
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
4501
--
4502

    
4503
CREATE OPERATOR => (
4504
    PROCEDURE = hstore,
4505
    LEFTARG = text[],
4506
    RIGHTARG = text
4507
);
4508

    
4509

    
4510
--
4511
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
4512
--
4513

    
4514
COMMENT ON OPERATOR => (text[], text) IS '
4515
usage: array[''key1'', ...]::text[] => ''value''
4516
';
4517

    
4518

    
4519
--
4520
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
4521
--
4522

    
4523
CREATE OPERATOR ?*>= (
4524
    PROCEDURE = is_populated_more_often_than,
4525
    LEFTARG = anyelement,
4526
    RIGHTARG = anyelement
4527
);
4528

    
4529

    
4530
--
4531
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
4532
--
4533

    
4534
CREATE OPERATOR ?>= (
4535
    PROCEDURE = is_more_complete_than,
4536
    LEFTARG = anyelement,
4537
    RIGHTARG = anyelement
4538
);
4539

    
4540

    
4541
--
4542
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4543
--
4544

    
4545
CREATE OPERATOR ||% (
4546
    PROCEDURE = concat_esc,
4547
    LEFTARG = text,
4548
    RIGHTARG = text
4549
);
4550

    
4551

    
4552
--
4553
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4554
--
4555

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

    
4560

    
4561
--
4562
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4563
--
4564

    
4565
CREATE TABLE map (
4566
    "from" text NOT NULL,
4567
    "to" text,
4568
    filter text,
4569
    notes text
4570
);
4571

    
4572

    
4573
--
4574
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4575
--
4576

    
4577

    
4578

    
4579
--
4580
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4581
--
4582

    
4583

    
4584

    
4585
--
4586
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4587
--
4588

    
4589
ALTER TABLE ONLY map
4590
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4591

    
4592

    
4593
--
4594
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4595
--
4596

    
4597
ALTER TABLE ONLY map
4598
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4599

    
4600

    
4601
--
4602
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4603
--
4604

    
4605
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4606

    
4607

    
4608
--
4609
-- PostgreSQL database dump complete
4610
--
4611

    
(21-21/32)