Project

General

Profile

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

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

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

    
16
CREATE SCHEMA util;
17

    
18

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

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

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

    
29

    
30
SET search_path = util, pg_catalog;
31

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

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

    
41

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

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

    
51

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

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

    
63

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

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

    
73

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

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

    
84

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

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

    
93

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

    
98
CREATE FUNCTION _alt("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown, "10" anyelement DEFAULT NULL::unknown, "11" anyelement DEFAULT NULL::unknown, "12" anyelement DEFAULT NULL::unknown) RETURNS anyelement
99
    LANGUAGE sql IMMUTABLE
100
    AS $_$
101
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
102
$_$;
103

    
104

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

    
109
CREATE FUNCTION _and("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
110
    LANGUAGE sql IMMUTABLE
111
    AS $_$
112
SELECT bool_and(value)
113
FROM
114
(VALUES
115
      ($1)
116
    , ($2)
117
    , ($3)
118
    , ($4)
119
    , ($5)
120
)
121
AS v (value)
122
$_$;
123

    
124

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

    
129
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
130
_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.
131
';
132

    
133

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

    
138
CREATE FUNCTION _avg("0" double precision DEFAULT NULL::double precision, "1" double precision DEFAULT NULL::double precision, "2" double precision DEFAULT NULL::double precision, "3" double precision DEFAULT NULL::double precision, "4" double precision DEFAULT NULL::double precision) RETURNS double precision
139
    LANGUAGE sql IMMUTABLE
140
    AS $_$
141
SELECT avg(value)
142
FROM
143
(VALUES
144
      ($1)
145
    , ($2)
146
    , ($3)
147
    , ($4)
148
    , ($5)
149
)
150
AS v (value)
151
$_$;
152

    
153

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

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

    
172

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

    
177
CREATE FUNCTION _dms_to_dd(deg double precision DEFAULT NULL::double precision, min double precision DEFAULT NULL::double precision, sec double precision DEFAULT NULL::double precision, dir compass_dir DEFAULT NULL::compass_dir) RETURNS double precision
178
    LANGUAGE sql IMMUTABLE
179
    AS $_$
180
SELECT sum(value)*COALESCE(util._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
181
FROM
182
(VALUES
183
      ($1)
184
    , ($2/60)
185
    , ($3/60/60)
186
)
187
AS v (value)
188
$_$;
189

    
190

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

    
195
CREATE FUNCTION _dms_to_dd(deg text DEFAULT NULL::text, min text DEFAULT NULL::text, sec text DEFAULT NULL::text, dir text DEFAULT NULL::text) RETURNS double precision
196
    LANGUAGE sql IMMUTABLE
197
    AS $_$
198
SELECT util._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::util.compass_dir)
199
$_$;
200

    
201

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

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

    
212

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

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

    
225

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

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

    
236

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

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

    
247

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

    
252
CREATE FUNCTION _join("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
253
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
256
$_$;
257

    
258

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

    
263
CREATE FUNCTION _join_words("0" text DEFAULT NULL::text, "1" text DEFAULT NULL::text, "2" text DEFAULT NULL::text, "3" text DEFAULT NULL::text, "4" text DEFAULT NULL::text, "5" text DEFAULT NULL::text, "6" text DEFAULT NULL::text, "7" text DEFAULT NULL::text, "8" text DEFAULT NULL::text, "9" text DEFAULT NULL::text) RETURNS text
264
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
267
$_$;
268

    
269

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

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

    
280

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

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

    
291

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

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

    
306

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

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

    
331

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

    
336
CREATE FUNCTION _max("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
337
    LANGUAGE sql IMMUTABLE
338
    AS $_$
339
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
340
$_$;
341

    
342

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

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

    
381

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

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

    
392

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

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

    
431

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

    
436
CREATE FUNCTION _min("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
437
    LANGUAGE sql IMMUTABLE
438
    AS $_$
439
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
440
$_$;
441

    
442

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

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

    
453

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

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

    
464

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

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

    
475

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

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

    
501

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

    
506
CREATE FUNCTION _or("0" boolean DEFAULT NULL::boolean, "1" boolean DEFAULT NULL::boolean, "2" boolean DEFAULT NULL::boolean, "3" boolean DEFAULT NULL::boolean, "4" boolean DEFAULT NULL::boolean) RETURNS boolean
507
    LANGUAGE sql IMMUTABLE
508
    AS $_$
509
SELECT bool_or(value)
510
FROM
511
(VALUES
512
      ($1)
513
    , ($2)
514
    , ($3)
515
    , ($4)
516
    , ($5)
517
)
518
AS v (value)
519
$_$;
520

    
521

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

    
526
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '
527
_or() ignores NULL values, while OR combines them with the other values to potentially convert false to NULL. OR should be used with required fields, and _or() with optional fields.
528
';
529

    
530

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

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

    
541

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

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

    
552

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

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

    
570

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

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

    
579

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

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

    
590

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

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

    
607

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

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

    
618

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

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

    
629

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

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

    
638

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

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

    
649

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

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

    
660

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

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

    
671

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

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

    
680

    
681
--
682
-- Name: auto_rm_freq(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
683
--
684

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

    
693

    
694
--
695
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: util; Owner: -
696
--
697

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

    
704

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

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

    
720

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

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

    
729

    
730
--
731
-- Name: col__min(col_ref); Type: FUNCTION; Schema: util; Owner: -
732
--
733

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

    
745

    
746
--
747
-- Name: col_comment(col_ref); Type: FUNCTION; Schema: util; Owner: -
748
--
749

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

    
769

    
770
--
771
-- Name: col_default_sql(col_ref); Type: FUNCTION; Schema: util; Owner: -
772
--
773

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

    
792

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

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

    
803

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

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

    
812

    
813
--
814
-- Name: col_exists(col_ref); Type: FUNCTION; Schema: util; Owner: -
815
--
816

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

    
828

    
829
--
830
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: util; Owner: -
831
--
832

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

    
845

    
846
--
847
-- Name: col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
848
--
849

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

    
859

    
860
--
861
-- Name: col_names(regtype); Type: FUNCTION; Schema: util; Owner: -
862
--
863

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

    
872

    
873
--
874
-- Name: col_type(col_ref); Type: FUNCTION; Schema: util; Owner: -
875
--
876

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

    
895

    
896
--
897
-- Name: comment(oid); Type: FUNCTION; Schema: util; Owner: -
898
--
899

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

    
906

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

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

    
917

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

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

    
928

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

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

    
939

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

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

    
950

    
951
--
952
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: util; Owner: -
953
--
954

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

    
973

    
974
--
975
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: util; Owner: -
976
--
977

    
978
COMMENT ON FUNCTION create_if_not_exists(sql text) IS '
979
idempotent
980
';
981

    
982

    
983
--
984
-- Name: curr_func(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
985
--
986

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

    
993

    
994
--
995
-- Name: debug_print_func_call(text); Type: FUNCTION; Schema: util; Owner: -
996
--
997

    
998
CREATE FUNCTION debug_print_func_call(func_call text) RETURNS void
999
    LANGUAGE sql IMMUTABLE
1000
    AS $_$
1001
SELECT util.raise('NOTICE', $$SELECT $$||$1)
1002
$_$;
1003

    
1004

    
1005
--
1006
-- Name: debug_print_return_value(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1007
--
1008

    
1009
CREATE FUNCTION debug_print_return_value(value anyelement, encode boolean DEFAULT false) RETURNS anyelement
1010
    LANGUAGE sql IMMUTABLE
1011
    AS $_$
1012
SELECT util.raise('NOTICE', 'returns: '
1013
||(CASE WHEN $2 THEN util.quote_typed($1) ELSE $1::text END));
1014
SELECT $1;
1015
$_$;
1016

    
1017

    
1018
--
1019
-- Name: debug_print_sql(text); Type: FUNCTION; Schema: util; Owner: -
1020
--
1021

    
1022
CREATE FUNCTION debug_print_sql(sql text) RETURNS void
1023
    LANGUAGE sql IMMUTABLE
1024
    AS $_$
1025
/* newline before so the query starts at the beginning of the line.
1026
newline after to visually separate queries from one another. */
1027
SELECT util.raise('NOTICE', $$
1028
$$||util.runnable_sql($1)||$$
1029
$$||COALESCE(util.explain2notice_msg_if_can($1), ''))
1030
$_$;
1031

    
1032

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

    
1037
CREATE FUNCTION derived_cols(table_ regclass, names regclass) RETURNS SETOF text
1038
    LANGUAGE sql STABLE
1039
    AS $_$
1040
SELECT util.eval2set($$
1041
SELECT col
1042
FROM util.col_names($$||quote_nullable($1)||$$::regclass) f (col)
1043
LEFT JOIN $$||$2||$$ ON "to" = col
1044
WHERE "from" IS NULL
1045
$$, NULL::text)
1046
$_$;
1047

    
1048

    
1049
--
1050
-- Name: FUNCTION derived_cols(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
1051
--
1052

    
1053
COMMENT ON FUNCTION derived_cols(table_ regclass, names regclass) IS '
1054
gets table_''s derived columns (all the columns not in the names table)
1055
';
1056

    
1057

    
1058
--
1059
-- Name: diff(regclass, regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
1060
--
1061

    
1062
CREATE FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1063
    LANGUAGE sql
1064
    AS $_$
1065
-- create a diff when the # of copies of a row differs between the tables
1066
SELECT util.to_freq($1);
1067
SELECT util.to_freq($2);
1068
SELECT util.auto_rm_freq(ARRAY[$1, $2]);
1069
SELECT util.try_create($$ALTER TABLE $$||util.typeof($3)||$$ ADD COLUMN copies bigint NOT NULL$$);
1070

    
1071
SELECT * FROM util.diff($1, $2, $3, has_freq := true)
1072
$_$;
1073

    
1074

    
1075
--
1076
-- Name: FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1077
--
1078

    
1079
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1080
usage:
1081
SELECT * FROM util.diff(''"left_table"''::regclass, ''"right_table"''::regclass, NULL::shared_base_type)
1082

    
1083
col_type_null (*required*): NULL::shared_base_type
1084
';
1085

    
1086

    
1087
--
1088
-- Name: diff(text, text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1089
--
1090

    
1091
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
1092
    LANGUAGE plpgsql
1093
    SET search_path TO pg_temp
1094
    AS $_$
1095
/* must use LANGUAGE plpgsql because LANGUAGE sql does not support runtime
1096
changes of search_path (schema elements are bound at inline time rather than
1097
runtime) */
1098
/* function option search_path is needed to limit the effects of
1099
`SET LOCAL search_path` to the current function */
1100
BEGIN
1101
	PERFORM util.use_schema($3); -- includes util.%== as default/fallback
1102
	
1103
	PERFORM util.mk_keys_func(pg_typeof($3));
1104
	RETURN QUERY
1105
		SELECT * FROM util.eval2col_pair(util.mk_diff_query($1, $2,
1106
$$/* need to explicitly cast each side to the return type because this does not
1107
happen automatically even when an implicit cast is available */
1108
  left_::$$||util.typeof($3)||$$
1109
, right_::$$||util.typeof($3)
1110
/* when using the util.%==(anyelement, anyelement) operator, you must cast to
1111
the *same* base type, *even though* this is optional when using a custom %== */
1112
, util._if($4, $$true/*= CROSS JOIN*/$$,
1113
$$ left_::$$||util.typeof($3)||$$
1114
%== right_::$$||util.typeof($3)||$$
1115
	-- refer to EXPLAIN output for expansion of %==$$
1116
)
1117
,     $$         left_::$$||util.typeof($3)||$$
1118
IS DISTINCT FROM right_::$$||util.typeof($3)
1119
), $3)
1120
	;
1121
END;
1122
$_$;
1123

    
1124

    
1125
--
1126
-- 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: -
1127
--
1128

    
1129
COMMENT ON FUNCTION diff(left__ text, right__ text, col_type_null anyelement, single_row boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1130
col_type_null (*required*): NULL::col_type
1131
single_row: whether the tables consist of a single row, which should be
1132
	displayed side-by-side
1133

    
1134
to match up rows using a subset of the columns, create a custom keys() function
1135
which returns this subset as a record:
1136
-- note that OUT parameters for the returned fields are *not* needed
1137
CREATE OR REPLACE FUNCTION [schema].keys(value [schema].[base_type])
1138
  RETURNS record AS
1139
$BODY$
1140
SELECT ($1.key_field_0, $1.key_field_1)
1141
$BODY$
1142
  LANGUAGE sql IMMUTABLE
1143
  COST 100;
1144

    
1145

    
1146
to run EXPLAIN on the FULL JOIN query:
1147
# run this function
1148
# look for a NOTICE containing the expanded query that it ran
1149
# run EXPLAIN on this expanded query
1150
';
1151

    
1152

    
1153
--
1154
-- Name: diff(regclass, regclass, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1155
--
1156

    
1157
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
1158
    LANGUAGE sql
1159
    AS $_$
1160
SELECT * FROM util.diff($1::text, $2::text, $3,
1161
	single_row := util.has_single_row($1) AND util.has_single_row($2))
1162
$_$;
1163

    
1164

    
1165
--
1166
-- 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: -
1167
--
1168

    
1169
COMMENT ON FUNCTION diff(left_table regclass, right_table regclass, col_type_null anyelement, has_freq boolean, OUT left_ anyelement, OUT right_ anyelement) IS '
1170
helper function used by diff(regclass, regclass)
1171

    
1172
usage:
1173
SELECT * FROM util.diff(''"left_freq_table"''::regclass, ''"right_freq_table"''::regclass, NULL::shared_base_type, has_freq := true)
1174

    
1175
col_type_null (*required*): NULL::shared_base_type
1176
';
1177

    
1178

    
1179
--
1180
-- Name: do_optionally_ignore(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1181
--
1182

    
1183
CREATE FUNCTION do_optionally_ignore(sql text, ignore boolean) RETURNS void
1184
    LANGUAGE sql
1185
    AS $_$
1186
SELECT CASE WHEN $2 THEN util.try_create($1) ELSE util.create_if_not_exists($1) END
1187
$_$;
1188

    
1189

    
1190
--
1191
-- Name: FUNCTION do_optionally_ignore(sql text, ignore boolean); Type: COMMENT; Schema: util; Owner: -
1192
--
1193

    
1194
COMMENT ON FUNCTION do_optionally_ignore(sql text, ignore boolean) IS '
1195
idempotent
1196
';
1197

    
1198

    
1199
--
1200
-- Name: drop_column(col_ref, boolean); Type: FUNCTION; Schema: util; Owner: -
1201
--
1202

    
1203
CREATE FUNCTION drop_column(col col_ref, force boolean DEFAULT false) RETURNS void
1204
    LANGUAGE sql
1205
    AS $_$
1206
SELECT util.eval($$ALTER TABLE $$||$1.table_||$$ DROP COLUMN IF EXISTS $$||
1207
quote_ident($1.name)||util._if($2, $$ CASCADE$$, ''::text))
1208
$_$;
1209

    
1210

    
1211
--
1212
-- Name: FUNCTION drop_column(col col_ref, force boolean); Type: COMMENT; Schema: util; Owner: -
1213
--
1214

    
1215
COMMENT ON FUNCTION drop_column(col col_ref, force boolean) IS '
1216
idempotent
1217
';
1218

    
1219

    
1220
--
1221
-- Name: drop_column(regclass[], text, boolean); Type: FUNCTION; Schema: util; Owner: -
1222
--
1223

    
1224
CREATE FUNCTION drop_column(tables regclass[], col text, force boolean DEFAULT false) RETURNS void
1225
    LANGUAGE sql
1226
    AS $_$
1227
SELECT util.drop_column((table_, $2), $3) FROM unnest($1) table_
1228
$_$;
1229

    
1230

    
1231
--
1232
-- Name: FUNCTION drop_column(tables regclass[], col text, force boolean); Type: COMMENT; Schema: util; Owner: -
1233
--
1234

    
1235
COMMENT ON FUNCTION drop_column(tables regclass[], col text, force boolean) IS '
1236
idempotent
1237
';
1238

    
1239

    
1240
--
1241
-- Name: drop_relation(anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1242
--
1243

    
1244
CREATE FUNCTION drop_relation(relation anyelement, force boolean DEFAULT false) RETURNS void
1245
    LANGUAGE sql
1246
    AS $_$
1247
/* use util.qual_name() instead of ::text so that the schema qualifier is always
1248
included in the debug SQL */
1249
SELECT util.drop_relation(util.relation_type($1), util.qual_name($1), $2)
1250
$_$;
1251

    
1252

    
1253
--
1254
-- Name: drop_relation(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1255
--
1256

    
1257
CREATE FUNCTION drop_relation(type text, relation_esc text, force boolean DEFAULT false) RETURNS void
1258
    LANGUAGE sql
1259
    AS $_$
1260
SELECT util.eval($$DROP $$||$1||$$ IF EXISTS $$||$2
1261
||util._if($3, $$ CASCADE$$, ''::text))
1262
$_$;
1263

    
1264

    
1265
--
1266
-- Name: FUNCTION drop_relation(type text, relation_esc text, force boolean); Type: COMMENT; Schema: util; Owner: -
1267
--
1268

    
1269
COMMENT ON FUNCTION drop_relation(type text, relation_esc text, force boolean) IS '
1270
idempotent
1271
';
1272

    
1273

    
1274
--
1275
-- Name: drop_relations_like(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1276
--
1277

    
1278
CREATE FUNCTION drop_relations_like(name_regexp text, schema_anchor anyelement, force boolean DEFAULT false) RETURNS void
1279
    LANGUAGE sql
1280
    AS $_$
1281
SELECT util.drop_relations_like($1, util.schema_regexp($2), $3)
1282
$_$;
1283

    
1284

    
1285
--
1286
-- Name: drop_relations_like(text, text, boolean); Type: FUNCTION; Schema: util; Owner: -
1287
--
1288

    
1289
CREATE FUNCTION drop_relations_like(name_regexp text, schema_regexp text DEFAULT ''::text, force boolean DEFAULT false) RETURNS void
1290
    LANGUAGE sql
1291
    AS $_$
1292
SELECT util.debug_print_func_call(util.quote_func_call(
1293
'util.drop_relations_like', util.quote_typed($1), util.quote_typed($2),
1294
util.quote_typed($3)))
1295
;
1296
SELECT util.drop_relation(relation, $3)
1297
FROM util.show_relations_like($1, $2) relation
1298
;
1299
SELECT NULL::void; -- don't fold away functions called in previous query
1300
$_$;
1301

    
1302

    
1303
--
1304
-- Name: drop_table(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1305
--
1306

    
1307
CREATE FUNCTION drop_table(table_ text, force boolean DEFAULT false) RETURNS void
1308
    LANGUAGE sql
1309
    AS $_$
1310
SELECT util.drop_relation('TABLE', $1, $2)
1311
$_$;
1312

    
1313

    
1314
--
1315
-- Name: FUNCTION drop_table(table_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1316
--
1317

    
1318
COMMENT ON FUNCTION drop_table(table_ text, force boolean) IS '
1319
idempotent
1320
';
1321

    
1322

    
1323
--
1324
-- Name: drop_view(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1325
--
1326

    
1327
CREATE FUNCTION drop_view(view_ text, force boolean DEFAULT false) RETURNS void
1328
    LANGUAGE sql
1329
    AS $_$
1330
SELECT util.drop_relation('VIEW', $1, $2)
1331
$_$;
1332

    
1333

    
1334
--
1335
-- Name: FUNCTION drop_view(view_ text, force boolean); Type: COMMENT; Schema: util; Owner: -
1336
--
1337

    
1338
COMMENT ON FUNCTION drop_view(view_ text, force boolean) IS '
1339
idempotent
1340
';
1341

    
1342

    
1343
--
1344
-- Name: empty_array(anyelement); Type: FUNCTION; Schema: util; Owner: -
1345
--
1346

    
1347
CREATE FUNCTION empty_array(elem_type_null anyelement DEFAULT NULL::text) RETURNS anyarray
1348
    LANGUAGE sql IMMUTABLE
1349
    AS $_$
1350
SELECT util.array_fill($1, 0)
1351
$_$;
1352

    
1353

    
1354
--
1355
-- Name: FUNCTION empty_array(elem_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1356
--
1357

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

    
1362

    
1363
--
1364
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1365
--
1366

    
1367
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
1368
    LANGUAGE sql IMMUTABLE
1369
    AS $_$
1370
SELECT (CASE WHEN util.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
1371
$_$;
1372

    
1373

    
1374
--
1375
-- Name: esc_name__append(text, text); Type: FUNCTION; Schema: util; Owner: -
1376
--
1377

    
1378
CREATE FUNCTION esc_name__append(suffix text, esc_name text) RETURNS text
1379
    LANGUAGE sql IMMUTABLE
1380
    AS $_$
1381
SELECT regexp_replace($2, '("?)$', $1||'\1')
1382
$_$;
1383

    
1384

    
1385
--
1386
-- Name: eval(text, boolean); Type: FUNCTION; Schema: util; Owner: -
1387
--
1388

    
1389
CREATE FUNCTION eval(sql text, verbose_ boolean DEFAULT true) RETURNS void
1390
    LANGUAGE plpgsql
1391
    AS $$
1392
BEGIN
1393
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1394
	EXECUTE sql;
1395
END;
1396
$$;
1397

    
1398

    
1399
--
1400
-- Name: eval2col_pair(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1401
--
1402

    
1403
CREATE FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) RETURNS SETOF record
1404
    LANGUAGE plpgsql
1405
    AS $$
1406
BEGIN
1407
	PERFORM util.debug_print_sql(sql);
1408
	RETURN QUERY EXECUTE sql;
1409
END;
1410
$$;
1411

    
1412

    
1413
--
1414
-- Name: FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement); Type: COMMENT; Schema: util; Owner: -
1415
--
1416

    
1417
COMMENT ON FUNCTION eval2col_pair(sql text, col_type_null anyelement, OUT left_ anyelement, OUT right_ anyelement) IS '
1418
col_type_null (*required*): NULL::col_type
1419
';
1420

    
1421

    
1422
--
1423
-- Name: eval2records(text); Type: FUNCTION; Schema: util; Owner: -
1424
--
1425

    
1426
CREATE FUNCTION eval2records(sql text) RETURNS SETOF record
1427
    LANGUAGE plpgsql
1428
    AS $$
1429
BEGIN
1430
	PERFORM util.debug_print_sql(sql);
1431
	RETURN QUERY EXECUTE sql;
1432
END;
1433
$$;
1434

    
1435

    
1436
--
1437
-- Name: eval2set(text, anyelement, boolean); Type: FUNCTION; Schema: util; Owner: -
1438
--
1439

    
1440
CREATE FUNCTION eval2set(sql text, ret_type_null anyelement DEFAULT NULL::text, verbose_ boolean DEFAULT true) RETURNS SETOF anyelement
1441
    LANGUAGE plpgsql
1442
    AS $$
1443
BEGIN
1444
	IF verbose_ THEN PERFORM util.debug_print_sql(sql); END IF;
1445
	RETURN QUERY EXECUTE sql;
1446
END;
1447
$$;
1448

    
1449

    
1450
--
1451
-- Name: eval2val(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1452
--
1453

    
1454
CREATE FUNCTION eval2val(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1455
    LANGUAGE plpgsql STABLE
1456
    AS $$
1457
DECLARE
1458
	ret_val ret_type_null%TYPE;
1459
BEGIN
1460
	PERFORM util.debug_print_sql(sql);
1461
	EXECUTE sql INTO STRICT ret_val;
1462
	RETURN ret_val;
1463
END;
1464
$$;
1465

    
1466

    
1467
--
1468
-- Name: FUNCTION eval2val(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1469
--
1470

    
1471
COMMENT ON FUNCTION eval2val(sql text, ret_type_null anyelement) IS '
1472
ret_type_null: NULL::ret_type
1473
';
1474

    
1475

    
1476
--
1477
-- Name: eval_expr(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1478
--
1479

    
1480
CREATE FUNCTION eval_expr(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1481
    LANGUAGE sql
1482
    AS $_$
1483
SELECT util.eval2val($$SELECT $$||$1, $2)
1484
$_$;
1485

    
1486

    
1487
--
1488
-- Name: FUNCTION eval_expr(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1489
--
1490

    
1491
COMMENT ON FUNCTION eval_expr(sql text, ret_type_null anyelement) IS '
1492
ret_type_null: NULL::ret_type
1493
';
1494

    
1495

    
1496
--
1497
-- Name: eval_expr_passthru(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
1498
--
1499

    
1500
CREATE FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement DEFAULT NULL::text) RETURNS anyelement
1501
    LANGUAGE sql
1502
    AS $_$
1503
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE util.eval_expr($1, $2) END
1504
$_$;
1505

    
1506

    
1507
--
1508
-- Name: FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement); Type: COMMENT; Schema: util; Owner: -
1509
--
1510

    
1511
COMMENT ON FUNCTION eval_expr_passthru(sql text, ret_type_null anyelement) IS '
1512
sql: can be NULL, which will be passed through
1513
ret_type_null: NULL::ret_type
1514
';
1515

    
1516

    
1517
--
1518
-- Name: existing_cols(regclass, text[]); Type: FUNCTION; Schema: util; Owner: -
1519
--
1520

    
1521
CREATE FUNCTION existing_cols(table_ regclass, VARIADIC col_names text[]) RETURNS SETOF text
1522
    LANGUAGE sql STABLE
1523
    AS $_$
1524
SELECT col_name
1525
FROM unnest($2) s (col_name)
1526
WHERE util.col_exists(($1, col_name))
1527
$_$;
1528

    
1529

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

    
1534
CREATE FUNCTION explain(sql text) RETURNS SETOF text
1535
    LANGUAGE sql
1536
    AS $_$
1537
SELECT util.eval2set($$EXPLAIN $$||$1, verbose_ := false)
1538
$_$;
1539

    
1540

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

    
1545
CREATE FUNCTION explain2notice(sql text) RETURNS void
1546
    LANGUAGE sql
1547
    AS $_$
1548
SELECT util.raise('NOTICE', util.explain2notice_msg($1))
1549
$_$;
1550

    
1551

    
1552
--
1553
-- Name: explain2notice_msg(text); Type: FUNCTION; Schema: util; Owner: -
1554
--
1555

    
1556
CREATE FUNCTION explain2notice_msg(sql text) RETURNS text
1557
    LANGUAGE sql
1558
    AS $_$
1559
-- newline before and after to visually separate it from other debug info
1560
SELECT $$
1561
EXPLAIN:
1562
$$||util.explain2str($1)||$$
1563
$$
1564
$_$;
1565

    
1566

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

    
1571
CREATE FUNCTION explain2notice_msg_if_can(sql text) RETURNS text
1572
    LANGUAGE sql
1573
    AS $_$
1574
SELECT (CASE WHEN util.is_explainable($1) THEN util.explain2notice_msg($1) END)
1575
$_$;
1576

    
1577

    
1578
--
1579
-- Name: explain2str(text); Type: FUNCTION; Schema: util; Owner: -
1580
--
1581

    
1582
CREATE FUNCTION explain2str(sql text) RETURNS text
1583
    LANGUAGE sql
1584
    AS $_$
1585
SELECT util.join_strs(explain, $$
1586
$$) FROM util.explain($1)
1587
$_$;
1588

    
1589

    
1590
SET default_tablespace = '';
1591

    
1592
SET default_with_oids = false;
1593

    
1594
--
1595
-- Name: explain; Type: TABLE; Schema: util; Owner: -; Tablespace: 
1596
--
1597

    
1598
CREATE TABLE explain (
1599
    line text NOT NULL
1600
);
1601

    
1602

    
1603
--
1604
-- Name: explain2table(text, regclass); Type: FUNCTION; Schema: util; Owner: -
1605
--
1606

    
1607
CREATE FUNCTION explain2table(sql text, table_ regclass DEFAULT 'explain'::regclass) RETURNS void
1608
    LANGUAGE sql
1609
    AS $_$
1610
SELECT util.eval($$INSERT INTO $$||$2||$$ SELECT util.explain(
1611
$$||quote_nullable($1)||$$
1612
)$$)
1613
$_$;
1614

    
1615

    
1616
--
1617
-- Name: FUNCTION explain2table(sql text, table_ regclass); Type: COMMENT; Schema: util; Owner: -
1618
--
1619

    
1620
COMMENT ON FUNCTION explain2table(sql text, table_ regclass) IS '
1621
usage:
1622
PERFORM util.explain2table($$
1623
query
1624
$$);
1625
';
1626

    
1627

    
1628
--
1629
-- Name: first_word(text); Type: FUNCTION; Schema: util; Owner: -
1630
--
1631

    
1632
CREATE FUNCTION first_word(str text) RETURNS text
1633
    LANGUAGE sql IMMUTABLE
1634
    AS $_$
1635
SELECT match[1] FROM regexp_matches(util.ltrim_nl($1), '^(\S*)') match
1636
$_$;
1637

    
1638

    
1639
--
1640
-- Name: fix_array(anyarray); Type: FUNCTION; Schema: util; Owner: -
1641
--
1642

    
1643
CREATE FUNCTION fix_array("array" anyarray) RETURNS anyarray
1644
    LANGUAGE sql IMMUTABLE
1645
    AS $_$
1646
SELECT CASE WHEN $1 IS NULL THEN NULL ELSE (
1647
	CASE WHEN pg_catalog.array_ndims($1) IS NULL THEN util.empty_array($1[1]) ELSE $1 END
1648
) END
1649
$_$;
1650

    
1651

    
1652
--
1653
-- Name: FUNCTION fix_array("array" anyarray); Type: COMMENT; Schema: util; Owner: -
1654
--
1655

    
1656
COMMENT ON FUNCTION fix_array("array" anyarray) IS '
1657
ensures that an array will always have proper non-NULL dimensions
1658
';
1659

    
1660

    
1661
--
1662
-- Name: force_recreate(text, text[]); Type: FUNCTION; Schema: util; Owner: -
1663
--
1664

    
1665
CREATE FUNCTION force_recreate(cmd text, users text[] DEFAULT NULL::text[]) RETURNS void
1666
    LANGUAGE plpgsql
1667
    AS $_$
1668
DECLARE
1669
	PG_EXCEPTION_DETAIL text;
1670
	recreate_users_cmd text = util.save_drop_views(users);
1671
BEGIN
1672
	PERFORM util.eval(cmd);
1673
	PERFORM util.eval(recreate_users_cmd);
1674
EXCEPTION
1675
WHEN dependent_objects_still_exist THEN
1676
	IF users IS NOT NULL THEN RAISE; END IF; -- save_drop_views() didn't fix it
1677
	GET STACKED DIAGNOSTICS PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL;
1678
	users = array(SELECT * FROM util.regexp_matches_group(
1679
		PG_EXCEPTION_DETAIL, '(?m)^view (.*) depends on table .*$'));
1680
	IF util.is_empty(users) THEN RAISE; END IF;
1681
	PERFORM util.force_recreate(cmd, users);
1682
END;
1683
$_$;
1684

    
1685

    
1686
--
1687
-- Name: FUNCTION force_recreate(cmd text, users text[]); Type: COMMENT; Schema: util; Owner: -
1688
--
1689

    
1690
COMMENT ON FUNCTION force_recreate(cmd text, users text[]) IS '
1691
idempotent
1692

    
1693
users: not necessary to provide this because it will be autopopulated
1694
';
1695

    
1696

    
1697
--
1698
-- Name: force_update_view(text, text); Type: FUNCTION; Schema: util; Owner: -
1699
--
1700

    
1701
CREATE FUNCTION force_update_view(view_ text, query text) RETURNS void
1702
    LANGUAGE plpgsql STRICT
1703
    AS $_$
1704
DECLARE
1705
	mk_view text = $$CREATE OR REPLACE VIEW $$||view_||$$ AS
1706
$$||query;
1707
BEGIN
1708
	EXECUTE mk_view;
1709
EXCEPTION
1710
WHEN invalid_table_definition THEN
1711
	IF SQLERRM = 'cannot drop columns from view'
1712
	OR SQLERRM LIKE 'cannot change name of view column "%" to "%"'
1713
	THEN
1714
		EXECUTE $$DROP VIEW $$||view_||$$ CASCADE$$;
1715
		EXECUTE mk_view;
1716
	ELSE RAISE USING ERRCODE = SQLSTATE, MESSAGE = SQLERRM;
1717
	END IF;
1718
END;
1719
$_$;
1720

    
1721

    
1722
--
1723
-- Name: FUNCTION force_update_view(view_ text, query text); Type: COMMENT; Schema: util; Owner: -
1724
--
1725

    
1726
COMMENT ON FUNCTION force_update_view(view_ text, query text) IS '
1727
idempotent
1728
';
1729

    
1730

    
1731
--
1732
-- Name: freq_always_1(regclass, text); Type: FUNCTION; Schema: util; Owner: -
1733
--
1734

    
1735
CREATE FUNCTION freq_always_1(table_ regclass, freq_col text DEFAULT 'copies'::text) RETURNS boolean
1736
    LANGUAGE sql STABLE
1737
    AS $_$
1738
SELECT util.eval2val(
1739
$$SELECT NOT EXISTS( -- there is no row that is != 1
1740
	SELECT NULL
1741
	FROM $$||$1||$$
1742
	WHERE $$||quote_ident(freq_col)||$$ IS DISTINCT FROM 1
1743
	LIMIT 1
1744
)
1745
$$, NULL::boolean)
1746
$_$;
1747

    
1748

    
1749
--
1750
-- Name: freq_always_1(regclass[], text); Type: FUNCTION; Schema: util; Owner: -
1751
--
1752

    
1753
CREATE FUNCTION freq_always_1(tables regclass[], freq_col text DEFAULT 'copies'::text) RETURNS boolean
1754
    LANGUAGE sql STABLE
1755
    AS $_$
1756
SELECT bool_and(util.freq_always_1(table_, $2)) FROM unnest($1) table_
1757
$_$;
1758

    
1759

    
1760
--
1761
-- Name: grants_users(); Type: FUNCTION; Schema: util; Owner: -
1762
--
1763

    
1764
CREATE FUNCTION grants_users() RETURNS SETOF text
1765
    LANGUAGE sql IMMUTABLE
1766
    AS $$
1767
VALUES ('bien_read'), ('public_')
1768
$$;
1769

    
1770

    
1771
--
1772
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: util; Owner: -
1773
--
1774

    
1775
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
1776
    LANGUAGE sql IMMUTABLE
1777
    AS $_$
1778
SELECT substring($2 for length($1)) = $1
1779
$_$;
1780

    
1781

    
1782
--
1783
-- Name: has_single_row(regclass); Type: FUNCTION; Schema: util; Owner: -
1784
--
1785

    
1786
CREATE FUNCTION has_single_row(table_ regclass) RETURNS boolean
1787
    LANGUAGE sql STABLE
1788
    AS $_$
1789
SELECT util.eval2val($$SELECT COUNT(*) = 1 FROM $$||$1, NULL::boolean)
1790
$_$;
1791

    
1792

    
1793
--
1794
-- Name: hstore(text[], text); Type: FUNCTION; Schema: util; Owner: -
1795
--
1796

    
1797
CREATE FUNCTION hstore(keys text[], value text) RETURNS hstore
1798
    LANGUAGE sql IMMUTABLE
1799
    AS $_$
1800
SELECT hstore(util.fix_array($1), util.array_fill($2, util.array_length($1)))
1801
$_$;
1802

    
1803

    
1804
--
1805
-- Name: FUNCTION hstore(keys text[], value text); Type: COMMENT; Schema: util; Owner: -
1806
--
1807

    
1808
COMMENT ON FUNCTION hstore(keys text[], value text) IS '
1809
avoids repeating the same value for each key
1810
';
1811

    
1812

    
1813
--
1814
-- Name: ifnull(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1815
--
1816

    
1817
CREATE FUNCTION ifnull(value anyelement, null_ anyelement) RETURNS anyelement
1818
    LANGUAGE sql IMMUTABLE
1819
    AS $_$
1820
SELECT COALESCE($1, $2)
1821
$_$;
1822

    
1823

    
1824
--
1825
-- Name: FUNCTION ifnull(value anyelement, null_ anyelement); Type: COMMENT; Schema: util; Owner: -
1826
--
1827

    
1828
COMMENT ON FUNCTION ifnull(value anyelement, null_ anyelement) IS '
1829
equivalent to MySQL''s IFNULL() (Postgres auto-lowercases the name)
1830
';
1831

    
1832

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

    
1837
CREATE FUNCTION inherit(derived regclass, base regclass) RETURNS void
1838
    LANGUAGE sql
1839
    AS $_$
1840
SELECT util.eval($$ALTER TABLE $$||$1||$$ INHERIT $$||$2)
1841
$_$;
1842

    
1843

    
1844
--
1845
-- Name: is_constant(col_ref); Type: FUNCTION; Schema: util; Owner: -
1846
--
1847

    
1848
CREATE FUNCTION is_constant(col col_ref) RETURNS boolean
1849
    LANGUAGE sql STABLE
1850
    AS $_$
1851
SELECT COALESCE(util.col_comment($1) LIKE 'constant%', false)
1852
$_$;
1853

    
1854

    
1855
--
1856
-- Name: is_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
1857
--
1858

    
1859
CREATE FUNCTION is_empty("array" anyarray) RETURNS boolean
1860
    LANGUAGE sql IMMUTABLE
1861
    AS $_$
1862
SELECT util.array_length($1) = 0
1863
$_$;
1864

    
1865

    
1866
--
1867
-- Name: is_explain(text); Type: FUNCTION; Schema: util; Owner: -
1868
--
1869

    
1870
CREATE FUNCTION is_explain(sql text) RETURNS boolean
1871
    LANGUAGE sql IMMUTABLE
1872
    AS $_$
1873
SELECT upper(util.first_word($1)) = 'EXPLAIN'
1874
$_$;
1875

    
1876

    
1877
--
1878
-- Name: is_explainable(text); Type: FUNCTION; Schema: util; Owner: -
1879
--
1880

    
1881
CREATE FUNCTION is_explainable(sql text) RETURNS boolean
1882
    LANGUAGE sql IMMUTABLE
1883
    AS $_$
1884
SELECT upper(util.first_word($1)) = ANY(
1885
'{SELECT,INSERT,UPDATE,DELETE,VALUES,EXECUTE,DECLARE}'::text[]
1886
/*from http://www.postgresql.org/docs/9.3/static/sql-explain.html#AEN77691*/
1887
)
1888
$_$;
1889

    
1890

    
1891
--
1892
-- Name: is_more_complete_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1893
--
1894

    
1895
CREATE FUNCTION is_more_complete_than("left" anyelement, "right" anyelement) RETURNS boolean
1896
    LANGUAGE sql IMMUTABLE
1897
    AS $_$
1898
SELECT $1 IS NOT DISTINCT FROM $2 OR ($1 IS NOT NULL AND $2 IS NULL)
1899
$_$;
1900

    
1901

    
1902
--
1903
-- Name: is_populated_more_often_than(anyelement, anyelement); Type: FUNCTION; Schema: util; Owner: -
1904
--
1905

    
1906
CREATE FUNCTION is_populated_more_often_than("left" anyelement, "right" anyelement) RETURNS boolean
1907
    LANGUAGE sql IMMUTABLE
1908
    AS $_$
1909
SELECT $1 IS NOT NULL >= $2 IS NOT NULL -- true > false
1910
$_$;
1911

    
1912

    
1913
--
1914
-- Name: is_set_stmt(text); Type: FUNCTION; Schema: util; Owner: -
1915
--
1916

    
1917
CREATE FUNCTION is_set_stmt(sql text) RETURNS boolean
1918
    LANGUAGE sql IMMUTABLE
1919
    AS $_$
1920
SELECT upper(util.first_word($1)) = 'SET'
1921
$_$;
1922

    
1923

    
1924
--
1925
-- Name: is_table(regclass); Type: FUNCTION; Schema: util; Owner: -
1926
--
1927

    
1928
CREATE FUNCTION is_table(relation regclass) RETURNS boolean
1929
    LANGUAGE sql STABLE
1930
    AS $_$
1931
SELECT relkind = 'r' FROM pg_class WHERE oid = $1
1932
$_$;
1933

    
1934

    
1935
--
1936
-- Name: is_view(regclass); Type: FUNCTION; Schema: util; Owner: -
1937
--
1938

    
1939
CREATE FUNCTION is_view(relation regclass) RETURNS boolean
1940
    LANGUAGE sql STABLE
1941
    AS $_$
1942
SELECT relkind = 'v' FROM pg_class WHERE oid = $1
1943
$_$;
1944

    
1945

    
1946
--
1947
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: util; Owner: -
1948
--
1949

    
1950
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
1951
    LANGUAGE sql IMMUTABLE STRICT
1952
    AS $_$
1953
SELECT $1 || $3 || $2
1954
$_$;
1955

    
1956

    
1957
--
1958
-- Name: FUNCTION join_strs_transform(state text, value text, delim text); Type: COMMENT; Schema: util; Owner: -
1959
--
1960

    
1961
COMMENT ON FUNCTION join_strs_transform(state text, value text, delim text) IS '
1962
must be declared STRICT to use the special handling of STRICT aggregating functions
1963
';
1964

    
1965

    
1966
--
1967
-- Name: keys(anyelement); Type: FUNCTION; Schema: util; Owner: -
1968
--
1969

    
1970
CREATE FUNCTION keys(value anyelement) RETURNS anyelement
1971
    LANGUAGE sql IMMUTABLE
1972
    AS $_$
1973
SELECT $1 -- compare on the entire value
1974
$_$;
1975

    
1976

    
1977
--
1978
-- Name: limit2row_num(integer, integer, integer); Type: FUNCTION; Schema: util; Owner: -
1979
--
1980

    
1981
CREATE FUNCTION limit2row_num(limit_ integer, offset_ integer DEFAULT NULL::integer, min_row_num integer DEFAULT 1) RETURNS integer
1982
    LANGUAGE sql IMMUTABLE
1983
    AS $_$
1984
SELECT COALESCE(util.offset2row_num($2, $3) + $1 - 1, 2147483647)
1985
$_$;
1986

    
1987

    
1988
--
1989
-- Name: ltrim_nl(text); Type: FUNCTION; Schema: util; Owner: -
1990
--
1991

    
1992
CREATE FUNCTION ltrim_nl(str text) RETURNS text
1993
    LANGUAGE sql IMMUTABLE
1994
    AS $_$
1995
SELECT ltrim($1, $$
1996
$$)
1997
$_$;
1998

    
1999

    
2000
--
2001
-- Name: map_filter_insert(); Type: FUNCTION; Schema: util; Owner: -
2002
--
2003

    
2004
CREATE FUNCTION map_filter_insert() RETURNS trigger
2005
    LANGUAGE plpgsql
2006
    AS $$
2007
BEGIN
2008
	IF new."from" LIKE ':%' THEN RETURN NULL; END IF; -- exclude metadata values
2009
	RETURN new;
2010
END;
2011
$$;
2012

    
2013

    
2014
--
2015
-- Name: map_get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2016
--
2017

    
2018
CREATE FUNCTION map_get(map regclass, key text) RETURNS text
2019
    LANGUAGE plpgsql STABLE STRICT
2020
    AS $_$
2021
DECLARE
2022
    value text;
2023
BEGIN
2024
    EXECUTE $$SELECT "to" FROM $$||map||$$ WHERE "from" = $1$$
2025
        INTO value USING key;
2026
    RETURN value;
2027
END;
2028
$_$;
2029

    
2030

    
2031
--
2032
-- Name: map_nulls(text[], anyelement); Type: FUNCTION; Schema: util; Owner: -
2033
--
2034

    
2035
CREATE FUNCTION map_nulls(nulls text[], value anyelement) RETURNS anyelement
2036
    LANGUAGE sql IMMUTABLE
2037
    AS $_$
2038
SELECT util._map(util.nulls_map($1), $2)
2039
$_$;
2040

    
2041

    
2042
--
2043
-- Name: FUNCTION map_nulls(nulls text[], value anyelement); Type: COMMENT; Schema: util; Owner: -
2044
--
2045

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

    
2049
[1] inlining of function calls, which is different from constant folding
2050
[2] _map()''s profiling query
2051
SELECT util._map(''"1"=>NULL, "2"=>NULL, "3"=>NULL, *=>*'', v) FROM unnest(array_fill(1, array[100000])) f (v)
2052
and map_nulls()''s profiling query
2053
SELECT util.map_nulls(array[1, 2, 3]::text[], v) FROM unnest(array_fill(1, array[100000])) f (v)
2054
both take ~920 ms.
2055
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.
2056
';
2057

    
2058

    
2059
--
2060
-- Name: map_values(regclass); Type: FUNCTION; Schema: util; Owner: -
2061
--
2062

    
2063
CREATE FUNCTION map_values(map regclass) RETURNS SETOF text
2064
    LANGUAGE plpgsql STABLE STRICT
2065
    AS $_$
2066
BEGIN
2067
    RETURN QUERY EXECUTE $$SELECT "to" FROM $$||map;
2068
END;
2069
$_$;
2070

    
2071

    
2072
--
2073
-- Name: materialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2074
--
2075

    
2076
CREATE FUNCTION materialize_query(table_esc text, sql text) RETURNS void
2077
    LANGUAGE sql
2078
    AS $_$
2079
SELECT util.create_if_not_exists($$CREATE TABLE $$||$1||$$ AS
2080
$$||util.ltrim_nl($2));
2081
-- make sure the created table has the correct estimated row count
2082
SELECT util.analyze_($1);
2083

    
2084
SELECT util.append_comment($1, '
2085
contents generated from:
2086
'||util.ltrim_nl($2)||';
2087
');
2088
$_$;
2089

    
2090

    
2091
--
2092
-- Name: FUNCTION materialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2093
--
2094

    
2095
COMMENT ON FUNCTION materialize_query(table_esc text, sql text) IS '
2096
idempotent
2097
';
2098

    
2099

    
2100
--
2101
-- Name: materialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2102
--
2103

    
2104
CREATE FUNCTION materialize_view(table_esc text, view_ regclass) RETURNS void
2105
    LANGUAGE sql
2106
    AS $_$
2107
SELECT util.materialize_query($1, $$SELECT * FROM $$||$2)
2108
$_$;
2109

    
2110

    
2111
--
2112
-- Name: FUNCTION materialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2113
--
2114

    
2115
COMMENT ON FUNCTION materialize_view(table_esc text, view_ regclass) IS '
2116
idempotent
2117
';
2118

    
2119

    
2120
--
2121
-- Name: mk_const_col(col_ref, anyelement); Type: FUNCTION; Schema: util; Owner: -
2122
--
2123

    
2124
CREATE FUNCTION mk_const_col(col col_ref, value anyelement) RETURNS void
2125
    LANGUAGE sql
2126
    AS $_$
2127
SELECT util.create_if_not_exists($$
2128
ALTER TABLE $$||$1.table_||$$ ADD COLUMN $$
2129
||quote_ident($1.name)||$$ $$||pg_typeof($2)||util.type_qual($2)||$$ DEFAULT $$
2130
||quote_literal($2)||$$;
2131
COMMENT ON COLUMN $$||$1.table_||$$.$$||quote_ident($1.name)||$$ IS '
2132
constant
2133
';
2134
$$)
2135
$_$;
2136

    
2137

    
2138
--
2139
-- Name: FUNCTION mk_const_col(col col_ref, value anyelement); Type: COMMENT; Schema: util; Owner: -
2140
--
2141

    
2142
COMMENT ON FUNCTION mk_const_col(col col_ref, value anyelement) IS '
2143
idempotent
2144
';
2145

    
2146

    
2147
--
2148
-- Name: mk_derived_col(col_ref, text, boolean); Type: FUNCTION; Schema: util; Owner: -
2149
--
2150

    
2151
CREATE FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean DEFAULT false) RETURNS void
2152
    LANGUAGE plpgsql STRICT
2153
    AS $_$
2154
DECLARE
2155
    type regtype = util.typeof(expr, col.table_::text::regtype);
2156
    col_name_sql text = quote_ident(col.name);
2157
BEGIN
2158
    PERFORM util.create_if_not_exists((CASE WHEN overwrite THEN '' ELSE $$
2159
ALTER TABLE $$||col.table_||$$ ADD   COLUMN $$||col_name_sql||$$      $$||type||$$;$$ END)||$$
2160
ALTER TABLE $$||col.table_||$$ ALTER COLUMN $$||col_name_sql||$$ TYPE $$||type||$$ USING
2161
$$||expr||$$;
2162
$$);
2163
END;
2164
$_$;
2165

    
2166

    
2167
--
2168
-- Name: FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean); Type: COMMENT; Schema: util; Owner: -
2169
--
2170

    
2171
COMMENT ON FUNCTION mk_derived_col(col col_ref, expr text, overwrite boolean) IS '
2172
idempotent
2173
';
2174

    
2175

    
2176
--
2177
-- Name: mk_diff_query(text, text, text, text, text); Type: FUNCTION; Schema: util; Owner: -
2178
--
2179

    
2180
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
2181
    LANGUAGE sql IMMUTABLE
2182
    AS $_$
2183
SELECT
2184
$$SELECT
2185
$$||$3||$$
2186
FROM      $$||$1||$$ left_
2187
FULL JOIN $$||$2||$$ right_
2188
ON $$||$4||$$
2189
WHERE $$||$5||$$
2190
ORDER BY left_, right_
2191
$$
2192
$_$;
2193

    
2194

    
2195
--
2196
-- Name: mk_keys_func(regtype); Type: FUNCTION; Schema: util; Owner: -
2197
--
2198

    
2199
CREATE FUNCTION mk_keys_func(type regtype) RETURNS void
2200
    LANGUAGE sql
2201
    AS $_$
2202
-- keys()
2203
SELECT util.mk_keys_func($1, ARRAY(
2204
SELECT col FROM util.typed_cols($1) col
2205
WHERE (col).type != ANY('{bigint}'::regtype[]) -- not a count col
2206
));
2207

    
2208
-- values_()
2209
SELECT util.mk_keys_func($1, COALESCE(
2210
	NULLIF(ARRAY(
2211
	SELECT col FROM util.typed_cols($1) col
2212
	WHERE (col).type = ANY('{bigint}'::regtype[]) -- is a count col
2213
	), ARRAY[]::util.col_cast[])
2214
, ARRAY(SELECT util.typed_cols($1))) -- no count cols, so use all cols
2215
, 'values_');
2216
$_$;
2217

    
2218

    
2219
--
2220
-- Name: mk_keys_func(regtype, col_cast[], text); Type: FUNCTION; Schema: util; Owner: -
2221
--
2222

    
2223
CREATE FUNCTION mk_keys_func(type regtype, cols col_cast[], name text DEFAULT 'keys'::text) RETURNS void
2224
    LANGUAGE sql
2225
    AS $_$
2226
SELECT util.create_if_not_exists($$
2227
CREATE TYPE $$||util.prefixed_name($3||'_', $1)||$$ AS
2228
($$||util.mk_typed_cols_list($2)||$$);
2229
COMMENT ON TYPE $$||util.prefixed_name($3||'_', $1)||$$ IS '
2230
autogenerated
2231
';
2232
$$);
2233

    
2234
SELECT util.mk_keys_func($1, util.prefixed_name($3||'_', $1)::regtype, $3);
2235
$_$;
2236

    
2237

    
2238
--
2239
-- Name: mk_keys_func(regtype, regtype, text); Type: FUNCTION; Schema: util; Owner: -
2240
--
2241

    
2242
CREATE FUNCTION mk_keys_func(type regtype, return_type regtype, name text DEFAULT 'keys'::text) RETURNS void
2243
    LANGUAGE sql
2244
    AS $_$
2245
SELECT util.create_if_not_exists($$
2246
CREATE FUNCTION $$||util.qual_name(util.schema($1), $3)||$$(value $$
2247
||util.qual_name($1)||$$)
2248
  RETURNS $$||util.qual_name($2)||$$ AS
2249
$BODY1$
2250
SELECT ROW($$||
2251
(SELECT COALESCE(string_agg($$$1.$$||quote_ident((col).col_name), ', '), '')
2252
FROM util.typed_cols($2) col) ||$$)::$$||util.qual_name($2)||$$
2253
$BODY1$
2254
  LANGUAGE sql IMMUTABLE
2255
  COST 100;
2256
$$);
2257
$_$;
2258

    
2259

    
2260
--
2261
-- Name: mk_map_table(text); Type: FUNCTION; Schema: util; Owner: -
2262
--
2263

    
2264
CREATE FUNCTION mk_map_table(table_ text) RETURNS void
2265
    LANGUAGE sql
2266
    AS $_$
2267
SELECT util.create_if_not_exists($$
2268
CREATE TABLE $$||$1||$$
2269
(
2270
    LIKE util.map INCLUDING ALL
2271
);
2272

    
2273
CREATE TRIGGER map_filter_insert
2274
  BEFORE INSERT
2275
  ON $$||$1||$$
2276
  FOR EACH ROW
2277
  EXECUTE PROCEDURE util.map_filter_insert();
2278
$$)
2279
$_$;
2280

    
2281

    
2282
--
2283
-- Name: mk_out_params(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2284
--
2285

    
2286
CREATE FUNCTION mk_out_params(cols col_cast[]) RETURNS text
2287
    LANGUAGE sql IMMUTABLE
2288
    AS $_$
2289
SELECT COALESCE(string_agg($$, OUT $$||(unnest).col_name||$$ $$||
2290
util.qual_name((unnest).type), ''), '')
2291
FROM unnest($1)
2292
$_$;
2293

    
2294

    
2295
--
2296
-- Name: mk_search_path(text[]); Type: FUNCTION; Schema: util; Owner: -
2297
--
2298

    
2299
CREATE FUNCTION mk_search_path(VARIADIC schemas text[]) RETURNS text
2300
    LANGUAGE sql IMMUTABLE
2301
    AS $_$
2302
SELECT string_agg(quote_ident(unnest), ', ') FROM unnest($1||'util'::text)
2303
$_$;
2304

    
2305

    
2306
--
2307
-- Name: FUNCTION mk_search_path(VARIADIC schemas text[]); Type: COMMENT; Schema: util; Owner: -
2308
--
2309

    
2310
COMMENT ON FUNCTION mk_search_path(VARIADIC schemas text[]) IS '
2311
auto-appends util to the search_path to enable use of util operators
2312
';
2313

    
2314

    
2315
--
2316
-- Name: mk_set_search_path(boolean); Type: FUNCTION; Schema: util; Owner: -
2317
--
2318

    
2319
CREATE FUNCTION mk_set_search_path(for_printing boolean DEFAULT false) RETURNS text
2320
    LANGUAGE sql IMMUTABLE
2321
    AS $_$
2322
SELECT util.mk_set_search_path(current_setting('search_path'), $1)
2323
$_$;
2324

    
2325

    
2326
--
2327
-- Name: mk_set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
2328
--
2329

    
2330
CREATE FUNCTION mk_set_search_path(search_path text, for_printing boolean DEFAULT false) RETURNS text
2331
    LANGUAGE sql IMMUTABLE
2332
    AS $_$
2333
/* debug_print_return_value() needed because this function is used with EXECUTE
2334
rather than util.eval() (in order to affect the calling function), so the
2335
search_path would not otherwise be printed */
2336
SELECT $$SET$$||util._if($2, $$ /*LOCAL*/$$::text, $$ LOCAL$$)
2337
||$$ search_path TO $$||$1
2338
$_$;
2339

    
2340

    
2341
--
2342
-- Name: mk_source_col(regclass); Type: FUNCTION; Schema: util; Owner: -
2343
--
2344

    
2345
CREATE FUNCTION mk_source_col(table_ regclass) RETURNS void
2346
    LANGUAGE sql
2347
    AS $_$
2348
SELECT util.mk_const_col(($1, 'source'), util.schema($1))
2349
$_$;
2350

    
2351

    
2352
--
2353
-- Name: FUNCTION mk_source_col(table_ regclass); Type: COMMENT; Schema: util; Owner: -
2354
--
2355

    
2356
COMMENT ON FUNCTION mk_source_col(table_ regclass) IS '
2357
idempotent
2358
';
2359

    
2360

    
2361
--
2362
-- Name: mk_subset_by_row_num_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2363
--
2364

    
2365
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass) RETURNS void
2366
    LANGUAGE plpgsql STRICT
2367
    AS $_$
2368
DECLARE
2369
	view_qual_name text = util.qual_name(view_);
2370
BEGIN
2371
	EXECUTE $$
2372
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2373
  RETURNS SETOF $$||view_||$$ AS
2374
$BODY1$
2375
SELECT * FROM $$||view_qual_name||$$
2376
ORDER BY sort_col
2377
LIMIT $1 OFFSET $2
2378
$BODY1$
2379
  LANGUAGE sql STABLE
2380
  COST 100
2381
  ROWS 1000
2382
$$;
2383
	
2384
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2385
END;
2386
$_$;
2387

    
2388

    
2389
--
2390
-- Name: mk_subset_by_row_num_func(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2391
--
2392

    
2393
CREATE FUNCTION mk_subset_by_row_num_func(view_ regclass, row_num_col text) RETURNS void
2394
    LANGUAGE plpgsql STRICT
2395
    AS $_$
2396
DECLARE
2397
	view_qual_name text = util.qual_name(view_);
2398
	row_num__min__fn text = util.esc_name__append('__row_num__min', view_qual_name);
2399
BEGIN
2400
	EXECUTE $$
2401
CREATE OR REPLACE FUNCTION $$||row_num__min__fn||$$()
2402
  RETURNS integer AS
2403
$BODY1$
2404
SELECT $$||quote_ident(row_num_col)||$$
2405
FROM $$||view_qual_name||$$
2406
ORDER BY $$||quote_ident(row_num_col)||$$ ASC
2407
LIMIT 1
2408
$BODY1$
2409
  LANGUAGE sql STABLE
2410
  COST 100;
2411
$$;
2412
	
2413
	EXECUTE $$
2414
CREATE OR REPLACE FUNCTION $$||view_||$$(limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2415
  RETURNS SETOF $$||view_||$$ AS
2416
$BODY1$
2417
SELECT * FROM $$||view_qual_name||$$
2418
WHERE $$||quote_ident(row_num_col)||$$ BETWEEN
2419
	util.offset2row_num(    $2, $$||row_num__min__fn||$$())
2420
AND util.limit2row_num ($1, $2, $$||row_num__min__fn||$$())
2421
ORDER BY $$||quote_ident(row_num_col)||$$
2422
$BODY1$
2423
  LANGUAGE sql STABLE
2424
  COST 100
2425
  ROWS 1000
2426
$$;
2427
	
2428
	PERFORM util.mk_subset_by_row_num_no_sort_func(view_);
2429
END;
2430
$_$;
2431

    
2432

    
2433
--
2434
-- Name: mk_subset_by_row_num_no_sort_func(regclass); Type: FUNCTION; Schema: util; Owner: -
2435
--
2436

    
2437
CREATE FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) RETURNS void
2438
    LANGUAGE plpgsql STRICT
2439
    AS $_$
2440
DECLARE
2441
	view_qual_name text = util.qual_name(view_);
2442
BEGIN
2443
	EXECUTE $$
2444
CREATE OR REPLACE FUNCTION $$||view_||$$(no_sort boolean, limit_ integer DEFAULT NULL::integer, offset_ integer DEFAULT NULL)
2445
  RETURNS SETOF $$||view_||$$
2446
  SET enable_sort TO 'off'
2447
  AS
2448
$BODY1$
2449
SELECT * FROM $$||view_qual_name||$$($2, $3)
2450
$BODY1$
2451
  LANGUAGE sql STABLE
2452
  COST 100
2453
  ROWS 1000
2454
;
2455
COMMENT ON FUNCTION $$||view_||$$(no_sort boolean, limit_ integer, offset_ integer) IS '
2456
Use this for limit values greater than ~100,000 to avoid unwanted slow sorts.
2457
If you want to run EXPLAIN and get expanded output, use the regular subset
2458
function instead. (When a config param is set on a function, EXPLAIN produces
2459
just a function scan.)
2460
';
2461
$$;
2462
END;
2463
$_$;
2464

    
2465

    
2466
--
2467
-- Name: FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass); Type: COMMENT; Schema: util; Owner: -
2468
--
2469

    
2470
COMMENT ON FUNCTION mk_subset_by_row_num_no_sort_func(view_ regclass) IS '
2471
creates subset function which turns off enable_sort
2472
';
2473

    
2474

    
2475
--
2476
-- Name: mk_typed_cols_list(col_cast[]); Type: FUNCTION; Schema: util; Owner: -
2477
--
2478

    
2479
CREATE FUNCTION mk_typed_cols_list(cols col_cast[]) RETURNS text
2480
    LANGUAGE sql IMMUTABLE
2481
    AS $_$
2482
SELECT COALESCE(string_agg(quote_ident((unnest).col_name)||$$ $$||
2483
util.qual_name((unnest).type), ', '), '')
2484
FROM unnest($1)
2485
$_$;
2486

    
2487

    
2488
--
2489
-- Name: name(regclass); Type: FUNCTION; Schema: util; Owner: -
2490
--
2491

    
2492
CREATE FUNCTION name(table_ regclass) RETURNS text
2493
    LANGUAGE sql STABLE
2494
    AS $_$
2495
SELECT relname::text FROM pg_class WHERE oid = $1
2496
$_$;
2497

    
2498

    
2499
--
2500
-- Name: name(regtype); Type: FUNCTION; Schema: util; Owner: -
2501
--
2502

    
2503
CREATE FUNCTION name(type regtype) RETURNS text
2504
    LANGUAGE sql STABLE
2505
    AS $_$
2506
SELECT typname::text FROM pg_type WHERE oid = $1
2507
$_$;
2508

    
2509

    
2510
--
2511
-- Name: name_was_truncated(text, integer); Type: FUNCTION; Schema: util; Owner: -
2512
--
2513

    
2514
CREATE FUNCTION name_was_truncated(name_ text, max_prefix_len integer DEFAULT 0) RETURNS boolean
2515
    LANGUAGE sql IMMUTABLE
2516
    AS $_$
2517
SELECT octet_length($1) >= util.namedatalen() - $2
2518
$_$;
2519

    
2520

    
2521
--
2522
-- Name: namedatalen(); Type: FUNCTION; Schema: util; Owner: -
2523
--
2524

    
2525
CREATE FUNCTION namedatalen() RETURNS integer
2526
    LANGUAGE sql IMMUTABLE
2527
    AS $$
2528
SELECT octet_length(repeat('_', 1024/*>63*/)::name::text)
2529
$$;
2530

    
2531

    
2532
--
2533
-- Name: not_empty(anyarray); Type: FUNCTION; Schema: util; Owner: -
2534
--
2535

    
2536
CREATE FUNCTION not_empty(value anyarray) RETURNS boolean
2537
    LANGUAGE sql IMMUTABLE
2538
    AS $_$
2539
SELECT $1 IS NOT NULL AND util.array_length($1) > 0
2540
$_$;
2541

    
2542

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

    
2547
CREATE FUNCTION not_null(value anyelement) RETURNS boolean
2548
    LANGUAGE sql IMMUTABLE
2549
    AS $_$
2550
SELECT $1 IS NOT NULL
2551
$_$;
2552

    
2553

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

    
2558
CREATE FUNCTION nulls_map(nulls text[]) RETURNS hstore
2559
    LANGUAGE sql IMMUTABLE
2560
    AS $_$
2561
SELECT util.hstore($1, NULL) || '*=>*'
2562
$_$;
2563

    
2564

    
2565
--
2566
-- Name: FUNCTION nulls_map(nulls text[]); Type: COMMENT; Schema: util; Owner: -
2567
--
2568

    
2569
COMMENT ON FUNCTION nulls_map(nulls text[]) IS '
2570
for use with _map()
2571
';
2572

    
2573

    
2574
--
2575
-- Name: offset2row_num(integer, integer); Type: FUNCTION; Schema: util; Owner: -
2576
--
2577

    
2578
CREATE FUNCTION offset2row_num(offset_ integer, min_row_num integer DEFAULT 1) RETURNS integer
2579
    LANGUAGE sql IMMUTABLE
2580
    AS $_$
2581
SELECT $2 + COALESCE($1, 0)
2582
$_$;
2583

    
2584

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

    
2589
CREATE FUNCTION parent(table_ regclass) RETURNS regclass
2590
    LANGUAGE sql STABLE
2591
    AS $_$
2592
SELECT inhparent FROM pg_inherits WHERE inhrelid = $1
2593
$_$;
2594

    
2595

    
2596
--
2597
-- Name: populate_table(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2598
--
2599

    
2600
CREATE FUNCTION populate_table(table_ regclass, sql text) RETURNS void
2601
    LANGUAGE sql
2602
    AS $_$
2603
SELECT util.eval($$INSERT INTO $$||$1||$$
2604
$$||util.ltrim_nl($2));
2605
-- make sure the created table has the correct estimated row count
2606
SELECT util.analyze_($1);
2607
$_$;
2608

    
2609

    
2610
--
2611
-- Name: prefixed_name(text, anyelement); Type: FUNCTION; Schema: util; Owner: -
2612
--
2613

    
2614
CREATE FUNCTION prefixed_name(prefix text, type anyelement) RETURNS text
2615
    LANGUAGE sql IMMUTABLE
2616
    AS $_$
2617
SELECT util.qual_name(util.schema($2), $1||util.name($2))
2618
$_$;
2619

    
2620

    
2621
--
2622
-- Name: prepend_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2623
--
2624

    
2625
CREATE FUNCTION prepend_comment(table_ regclass, comment text) RETURNS void
2626
    LANGUAGE sql
2627
    AS $_$
2628
SELECT util.set_comment($1, concat($2, util.comment($1)))
2629
$_$;
2630

    
2631

    
2632
--
2633
-- Name: FUNCTION prepend_comment(table_ regclass, comment text); Type: COMMENT; Schema: util; Owner: -
2634
--
2635

    
2636
COMMENT ON FUNCTION prepend_comment(table_ regclass, comment text) IS '
2637
comment: must start and end with a newline
2638
';
2639

    
2640

    
2641
--
2642
-- Name: qual_name(text[]); Type: FUNCTION; Schema: util; Owner: -
2643
--
2644

    
2645
CREATE FUNCTION qual_name(VARIADIC elems text[]) RETURNS text
2646
    LANGUAGE sql IMMUTABLE
2647
    AS $_$
2648
SELECT string_agg(quote_ident(unnest), '.') FROM unnest($1)
2649
$_$;
2650

    
2651

    
2652
--
2653
-- Name: qual_name(regclass); Type: FUNCTION; Schema: util; Owner: -
2654
--
2655

    
2656
CREATE FUNCTION qual_name(table_ regclass) RETURNS text
2657
    LANGUAGE sql STABLE
2658
    SET search_path TO pg_temp
2659
    AS $_$
2660
SELECT $1::text
2661
$_$;
2662

    
2663

    
2664
--
2665
-- Name: qual_name(regtype); Type: FUNCTION; Schema: util; Owner: -
2666
--
2667

    
2668
CREATE FUNCTION qual_name(type regtype) RETURNS text
2669
    LANGUAGE sql STABLE
2670
    SET search_path TO pg_temp
2671
    AS $_$
2672
SELECT $1::text
2673
$_$;
2674

    
2675

    
2676
--
2677
-- Name: FUNCTION qual_name(type regtype); Type: COMMENT; Schema: util; Owner: -
2678
--
2679

    
2680
COMMENT ON FUNCTION qual_name(type regtype) IS '
2681
a type''s schema-qualified name
2682
';
2683

    
2684

    
2685
--
2686
-- Name: qual_name(unknown); Type: FUNCTION; Schema: util; Owner: -
2687
--
2688

    
2689
CREATE FUNCTION qual_name(type unknown) RETURNS text
2690
    LANGUAGE sql STABLE
2691
    AS $_$
2692
SELECT util.qual_name($1::text::regtype)
2693
$_$;
2694

    
2695

    
2696
--
2697
-- Name: quote_func_call(regprocedure, text[]); Type: FUNCTION; Schema: util; Owner: -
2698
--
2699

    
2700
CREATE FUNCTION quote_func_call(func regprocedure, VARIADIC args_esc text[]) RETURNS text
2701
    LANGUAGE sql IMMUTABLE
2702
    AS $_$
2703
SELECT util.quote_func_call($1::regproc::text, VARIADIC $2)
2704
$_$;
2705

    
2706

    
2707
--
2708
-- Name: quote_func_call(text, text[]); Type: FUNCTION; Schema: util; Owner: -
2709
--
2710

    
2711
CREATE FUNCTION quote_func_call(func_esc text, VARIADIC args_esc text[]) RETURNS text
2712
    LANGUAGE sql IMMUTABLE
2713
    AS $_$
2714
SELECT $1||'('||concat_ws(', ', VARIADIC $2)||')'
2715
$_$;
2716

    
2717

    
2718
--
2719
-- Name: quote_typed(anyelement); Type: FUNCTION; Schema: util; Owner: -
2720
--
2721

    
2722
CREATE FUNCTION quote_typed(value anyelement) RETURNS text
2723
    LANGUAGE sql IMMUTABLE
2724
    AS $_$
2725
SELECT quote_nullable($1)||$$::$$||util.qual_name(pg_typeof($1))
2726
$_$;
2727

    
2728

    
2729
--
2730
-- Name: raise(text, text); Type: FUNCTION; Schema: util; Owner: -
2731
--
2732

    
2733
CREATE FUNCTION raise(type text, msg text) RETURNS void
2734
    LANGUAGE sql IMMUTABLE
2735
    AS $_X$
2736
SELECT util.eval($$
2737
CREATE OR REPLACE FUNCTION pg_temp.__raise()
2738
  RETURNS void AS
2739
-- $__BODY1$ in case msg contains $BODY1$ (in SQL)
2740
$__BODY1$
2741
BEGIN
2742
	RAISE $$||$1||$$ USING MESSAGE = $$||quote_nullable($2)||$$;
2743
END;
2744
$__BODY1$
2745
  LANGUAGE plpgsql IMMUTABLE
2746
  COST 100;
2747
$$, verbose_ := false);
2748

    
2749
SELECT util.eval($$SELECT pg_temp.__raise()$$, verbose_ := false);
2750
$_X$;
2751

    
2752

    
2753
--
2754
-- Name: FUNCTION raise(type text, msg text); Type: COMMENT; Schema: util; Owner: -
2755
--
2756

    
2757
COMMENT ON FUNCTION raise(type text, msg text) IS '
2758
type: a log level from
2759
http://www.postgresql.org/docs/9.3/static/plpgsql-errors-and-messages.html
2760
or a condition name from
2761
http://www.postgresql.org/docs/9.3/static/errcodes-appendix.html
2762
';
2763

    
2764

    
2765
--
2766
-- Name: raise_error_warning(text); Type: FUNCTION; Schema: util; Owner: -
2767
--
2768

    
2769
CREATE FUNCTION raise_error_warning(msg text) RETURNS void
2770
    LANGUAGE sql IMMUTABLE
2771
    AS $_$
2772
SELECT util.raise('WARNING', 'ERROR:  '||$1)
2773
$_$;
2774

    
2775

    
2776
--
2777
-- Name: raise_undefined_column(col_ref); Type: FUNCTION; Schema: util; Owner: -
2778
--
2779

    
2780
CREATE FUNCTION raise_undefined_column(col col_ref) RETURNS text
2781
    LANGUAGE plpgsql IMMUTABLE STRICT
2782
    AS $$
2783
BEGIN
2784
	RAISE undefined_column USING MESSAGE = concat('undefined column: ', col.name);
2785
END;
2786
$$;
2787

    
2788

    
2789
--
2790
-- Name: regexp_matches_group(text, text, integer); Type: FUNCTION; Schema: util; Owner: -
2791
--
2792

    
2793
CREATE FUNCTION regexp_matches_group(str text, re text, group_ integer DEFAULT 1) RETURNS SETOF text
2794
    LANGUAGE sql IMMUTABLE
2795
    AS $_$
2796
SELECT regexp_matches[$3] FROM regexp_matches($1, $2, 'g')
2797
$_$;
2798

    
2799

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

    
2804
CREATE FUNCTION regexp_quote(str text) RETURNS text
2805
    LANGUAGE sql IMMUTABLE
2806
    AS $_$
2807
SELECT regexp_replace($1, '\W', /*\char*/'\\\&', 'g')
2808
$_$;
2809

    
2810

    
2811
--
2812
-- Name: regprocedure(text); Type: FUNCTION; Schema: util; Owner: -
2813
--
2814

    
2815
CREATE FUNCTION regprocedure(func text) RETURNS regprocedure
2816
    LANGUAGE sql IMMUTABLE
2817
    AS $_$
2818
SELECT (CASE WHEN right($1, 1) = ')'
2819
THEN $1::regprocedure ELSE $1::regproc::regprocedure END)
2820
$_$;
2821

    
2822

    
2823
--
2824
-- Name: relation_type(regclass); Type: FUNCTION; Schema: util; Owner: -
2825
--
2826

    
2827
CREATE FUNCTION relation_type(relation regclass) RETURNS text
2828
    LANGUAGE sql STABLE
2829
    AS $_$
2830
SELECT util.relation_type(util.relation_type_char($1))
2831
$_$;
2832

    
2833

    
2834
--
2835
-- Name: relation_type("char"); Type: FUNCTION; Schema: util; Owner: -
2836
--
2837

    
2838
CREATE FUNCTION relation_type(relation_type_char "char") RETURNS text
2839
    LANGUAGE sql IMMUTABLE
2840
    AS $_$
2841
SELECT 'c=>TYPE, r=>TABLE, v=>VIEW'::hstore -> $1
2842
$_$;
2843

    
2844

    
2845
--
2846
-- Name: relation_type(regtype); Type: FUNCTION; Schema: util; Owner: -
2847
--
2848

    
2849
CREATE FUNCTION relation_type(type regtype) RETURNS text
2850
    LANGUAGE sql IMMUTABLE
2851
    AS $$
2852
SELECT 'TYPE'::text
2853
$$;
2854

    
2855

    
2856
--
2857
-- Name: relation_type_char(regclass); Type: FUNCTION; Schema: util; Owner: -
2858
--
2859

    
2860
CREATE FUNCTION relation_type_char(relation regclass) RETURNS "char"
2861
    LANGUAGE sql STABLE
2862
    AS $_$
2863
SELECT relkind FROM pg_class WHERE oid = $1
2864
$_$;
2865

    
2866

    
2867
--
2868
-- Name: remake_diff_table(text, regclass, regclass, text); Type: FUNCTION; Schema: util; Owner: -
2869
--
2870

    
2871
CREATE FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) RETURNS void
2872
    LANGUAGE sql
2873
    AS $_$
2874
/* can't have in_table/out_table inherit from *each other*, because inheritance
2875
also causes the rows of the parent table to be included in the child table.
2876
instead, they need to inherit from a common, empty table. */
2877
SELECT util.create_if_not_exists($$SELECT $$||util.quote_func_call(
2878
'util.copy_struct', util.quote_typed($2), util.quote_typed($4)));
2879
SELECT util.inherit($2, $4);
2880
SELECT util.inherit($3, $4);
2881

    
2882
SELECT util.rematerialize_query($1, $$
2883
SELECT * FROM util.diff(
2884
  $$||util.quote_typed($2)||$$
2885
, $$||util.quote_typed($3)||$$
2886
, NULL::$$||$4||$$)
2887
$$);
2888

    
2889
/* the table unfortunately cannot be *materialized* in human-readable form,
2890
because this would create column name collisions between the two sides */
2891
SELECT util.prepend_comment($1, '
2892
to view this table in human-readable form (with each side''s tuple column
2893
expanded to its component fields):
2894
SELECT (left_).*, ('||util.schema($4::regclass)||'.values_(right_)).* FROM '||$1||';
2895
');
2896
$_$;
2897

    
2898

    
2899
--
2900
-- Name: FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text); Type: COMMENT; Schema: util; Owner: -
2901
--
2902

    
2903
COMMENT ON FUNCTION remake_diff_table(diff_table text, left_table regclass, right_table regclass, type_table text) IS '
2904
type_table (*required*): table to create as the shared base type
2905
';
2906

    
2907

    
2908
--
2909
-- Name: rematerialize_query(text, text); Type: FUNCTION; Schema: util; Owner: -
2910
--
2911

    
2912
CREATE FUNCTION rematerialize_query(table_esc text, sql text) RETURNS void
2913
    LANGUAGE sql
2914
    AS $_$
2915
SELECT util.drop_table($1);
2916
SELECT util.materialize_query($1, $2);
2917
$_$;
2918

    
2919

    
2920
--
2921
-- Name: FUNCTION rematerialize_query(table_esc text, sql text); Type: COMMENT; Schema: util; Owner: -
2922
--
2923

    
2924
COMMENT ON FUNCTION rematerialize_query(table_esc text, sql text) IS '
2925
idempotent, but repeats action each time
2926
';
2927

    
2928

    
2929
--
2930
-- Name: rematerialize_view(text, regclass); Type: FUNCTION; Schema: util; Owner: -
2931
--
2932

    
2933
CREATE FUNCTION rematerialize_view(table_esc text, view_ regclass) RETURNS void
2934
    LANGUAGE sql
2935
    AS $_$
2936
SELECT util.drop_table($1);
2937
SELECT util.materialize_view($1, $2);
2938
$_$;
2939

    
2940

    
2941
--
2942
-- Name: FUNCTION rematerialize_view(table_esc text, view_ regclass); Type: COMMENT; Schema: util; Owner: -
2943
--
2944

    
2945
COMMENT ON FUNCTION rematerialize_view(table_esc text, view_ regclass) IS '
2946
idempotent, but repeats action each time
2947
';
2948

    
2949

    
2950
--
2951
-- Name: rename_cols(regclass, anyelement); Type: FUNCTION; Schema: util; Owner: -
2952
--
2953

    
2954
CREATE FUNCTION rename_cols(table_ regclass, renames anyelement) RETURNS void
2955
    LANGUAGE sql
2956
    AS $_$
2957
SELECT util.try_create($$ALTER TABLE $$||$1||$$ RENAME $$
2958
||quote_ident(name)||$$ TO $$||quote_ident($2 -> name))
2959
FROM util.col_names($1::text::regtype) f (name);
2960
SELECT NULL::void; -- don't fold away functions called in previous query
2961
$_$;
2962

    
2963

    
2964
--
2965
-- Name: FUNCTION rename_cols(table_ regclass, renames anyelement); Type: COMMENT; Schema: util; Owner: -
2966
--
2967

    
2968
COMMENT ON FUNCTION rename_cols(table_ regclass, renames anyelement) IS '
2969
idempotent
2970
';
2971

    
2972

    
2973
--
2974
-- Name: rename_relation(regclass, text); Type: FUNCTION; Schema: util; Owner: -
2975
--
2976

    
2977
CREATE FUNCTION rename_relation(from_ regclass, to_ text) RETURNS void
2978
    LANGUAGE sql
2979
    AS $_$
2980
/* use util.qual_name() instead of ::text so that the schema qualifier is always
2981
included in the debug SQL */
2982
SELECT util.rename_relation(util.qual_name($1), $2)
2983
$_$;
2984

    
2985

    
2986
--
2987
-- Name: rename_relation(text, text); Type: FUNCTION; Schema: util; Owner: -
2988
--
2989

    
2990
CREATE FUNCTION rename_relation(from_esc text, to_name text) RETURNS void
2991
    LANGUAGE sql
2992
    AS $_$
2993
/* 'ALTER TABLE can be used with views too'
2994
(http://www.postgresql.org/docs/9.3/static/sql-alterview.html) */
2995
SELECT util.eval($$ALTER TABLE IF EXISTS $$||$1||$$ RENAME TO $$
2996
||quote_ident($2))
2997
$_$;
2998

    
2999

    
3000
--
3001
-- Name: FUNCTION rename_relation(from_esc text, to_name text); Type: COMMENT; Schema: util; Owner: -
3002
--
3003

    
3004
COMMENT ON FUNCTION rename_relation(from_esc text, to_name text) IS '
3005
idempotent
3006
';
3007

    
3008

    
3009
--
3010
-- Name: replace_suffix(text, text, text, integer); Type: FUNCTION; Schema: util; Owner: -
3011
--
3012

    
3013
CREATE FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer DEFAULT 0) RETURNS text
3014
    LANGUAGE sql IMMUTABLE
3015
    AS $_$
3016
SELECT regexp_replace($1, util.truncated_prefixed_name_regexp($2, $4), '\1'||$3)
3017
$_$;
3018

    
3019

    
3020
--
3021
-- Name: FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer); Type: COMMENT; Schema: util; Owner: -
3022
--
3023

    
3024
COMMENT ON FUNCTION replace_suffix(str text, old_suffix text, new_suffix text, max_prefix_len integer) IS '
3025
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 
3026
';
3027

    
3028

    
3029
--
3030
-- Name: reset_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3031
--
3032

    
3033
CREATE FUNCTION reset_col_names(table_ regclass, names regclass) RETURNS void
3034
    LANGUAGE sql
3035
    AS $_$
3036
SELECT util.eval($$DELETE FROM $$||$2||$$ WHERE "from" LIKE ':%'$$);
3037
SELECT util.mk_derived_col(($2, 'to'), $$"from"$$, overwrite := true);
3038
SELECT util.set_col_names($1, $2);
3039
$_$;
3040

    
3041

    
3042
--
3043
-- Name: FUNCTION reset_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3044
--
3045

    
3046
COMMENT ON FUNCTION reset_col_names(table_ regclass, names regclass) IS '
3047
idempotent.
3048
alters the names table, so it will need to be repopulated after running this function.
3049
';
3050

    
3051

    
3052
--
3053
-- Name: reset_map_table(text); Type: FUNCTION; Schema: util; Owner: -
3054
--
3055

    
3056
CREATE FUNCTION reset_map_table(table_ text) RETURNS void
3057
    LANGUAGE sql
3058
    AS $_$
3059
SELECT util.drop_table($1);
3060
SELECT util.mk_map_table($1);
3061
$_$;
3062

    
3063

    
3064
--
3065
-- Name: rtrim_n(text, integer); Type: FUNCTION; Schema: util; Owner: -
3066
--
3067

    
3068
CREATE FUNCTION rtrim_n(str text, count integer) RETURNS text
3069
    LANGUAGE sql IMMUTABLE
3070
    AS $_$
3071
SELECT (CASE WHEN $2 <= 0 THEN $1 ELSE left($1, -$2) END)
3072
$_$;
3073

    
3074

    
3075
--
3076
-- Name: runnable_sql(text); Type: FUNCTION; Schema: util; Owner: -
3077
--
3078

    
3079
CREATE FUNCTION runnable_sql(sql text) RETURNS text
3080
    LANGUAGE sql IMMUTABLE
3081
    AS $_$
3082
SELECT (CASE WHEN util.is_set_stmt($1) THEN ''
3083
ELSE util.mk_set_search_path(for_printing := true)||$$;
3084
$$ END)||$1
3085
$_$;
3086

    
3087

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

    
3092
CREATE FUNCTION save_drop_view(view_ text) RETURNS text
3093
    LANGUAGE plpgsql STRICT
3094
    AS $_$
3095
DECLARE
3096
	result text = NULL;
3097
BEGIN
3098
	BEGIN
3099
		result = util.show_create_view(view_);
3100
		PERFORM util.eval($$DROP VIEW $$||view_);
3101
	EXCEPTION
3102
		WHEN undefined_table THEN NULL;
3103
	END;
3104
	RETURN result;
3105
END;
3106
$_$;
3107

    
3108

    
3109
--
3110
-- Name: save_drop_views(text[]); Type: FUNCTION; Schema: util; Owner: -
3111
--
3112

    
3113
CREATE FUNCTION save_drop_views(views text[]) RETURNS text
3114
    LANGUAGE sql
3115
    AS $_$
3116
SELECT string_agg(util.save_drop_view(unnest), '') FROM unnest($1)
3117
$_$;
3118

    
3119

    
3120
--
3121
-- Name: schema(oid); Type: FUNCTION; Schema: util; Owner: -
3122
--
3123

    
3124
CREATE FUNCTION schema(pg_namespace_oid oid) RETURNS text
3125
    LANGUAGE sql STABLE
3126
    AS $_$
3127
SELECT nspname::text FROM pg_namespace WHERE pg_namespace.oid = $1
3128
$_$;
3129

    
3130

    
3131
--
3132
-- Name: schema(regclass); Type: FUNCTION; Schema: util; Owner: -
3133
--
3134

    
3135
CREATE FUNCTION schema(table_ regclass) RETURNS text
3136
    LANGUAGE sql STABLE
3137
    AS $_$
3138
SELECT util.schema(relnamespace) FROM pg_class WHERE oid = $1
3139
$_$;
3140

    
3141

    
3142
--
3143
-- Name: schema(regtype); Type: FUNCTION; Schema: util; Owner: -
3144
--
3145

    
3146
CREATE FUNCTION schema(type regtype) RETURNS text
3147
    LANGUAGE sql STABLE
3148
    AS $_$
3149
SELECT util.schema(typnamespace) FROM pg_type WHERE oid = $1
3150
$_$;
3151

    
3152

    
3153
--
3154
-- Name: schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3155
--
3156

    
3157
CREATE FUNCTION schema(type_null anyelement) RETURNS text
3158
    LANGUAGE sql STABLE
3159
    AS $_$
3160
SELECT util.schema(pg_typeof($1))
3161
$_$;
3162

    
3163

    
3164
--
3165
-- Name: schema_bundle_get_schemas(text); Type: FUNCTION; Schema: util; Owner: -
3166
--
3167

    
3168
CREATE FUNCTION schema_bundle_get_schemas(schema_bundle text) RETURNS SETOF text
3169
    LANGUAGE sql STABLE
3170
    AS $_$
3171
SELECT nspname::text FROM pg_namespace WHERE nspname ~ ('^'||$1||'(?=\y|_)')
3172
$_$;
3173

    
3174

    
3175
--
3176
-- Name: FUNCTION schema_bundle_get_schemas(schema_bundle text); Type: COMMENT; Schema: util; Owner: -
3177
--
3178

    
3179
COMMENT ON FUNCTION schema_bundle_get_schemas(schema_bundle text) IS '
3180
a schema bundle is a group of schemas with a common prefix
3181
';
3182

    
3183

    
3184
--
3185
-- Name: schema_bundle_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3186
--
3187

    
3188
CREATE FUNCTION schema_bundle_rename(old text, new text) RETURNS void
3189
    LANGUAGE sql
3190
    AS $_$
3191
SELECT util.schema_rename(old_schema,
3192
	overlay(old_schema placing new from 1 for length(old))) -- replace prefix
3193
FROM util.schema_bundle_get_schemas($1) f (old_schema);
3194
SELECT NULL::void; -- don't fold away functions called in previous query
3195
$_$;
3196

    
3197

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

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

    
3214

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

    
3219
CREATE FUNCTION schema_bundle_rm(schema_bundle text) RETURNS void
3220
    LANGUAGE sql
3221
    AS $_$
3222
SELECT util.schema_rm(schema)
3223
FROM util.schema_bundle_get_schemas($1) f (schema);
3224
SELECT NULL::void; -- don't fold away functions called in previous query
3225
$_$;
3226

    
3227

    
3228
--
3229
-- Name: schema_esc(anyelement); Type: FUNCTION; Schema: util; Owner: -
3230
--
3231

    
3232
CREATE FUNCTION schema_esc(type_null anyelement) RETURNS text
3233
    LANGUAGE sql STABLE
3234
    AS $_$
3235
SELECT quote_ident(util.schema($1))
3236
$_$;
3237

    
3238

    
3239
--
3240
-- Name: schema_matches(text, text); Type: FUNCTION; Schema: util; Owner: -
3241
--
3242

    
3243
CREATE FUNCTION schema_matches(schema text, schema_regexp text) RETURNS boolean
3244
    LANGUAGE sql IMMUTABLE
3245
    AS $_$
3246
SELECT $1 ~ $2 AND /*in userspace*/$1 !~ '^(?:information_schema|pg_.*)$'
3247
$_$;
3248

    
3249

    
3250
--
3251
-- Name: schema_oid(text); Type: FUNCTION; Schema: util; Owner: -
3252
--
3253

    
3254
CREATE FUNCTION schema_oid(schema text) RETURNS oid
3255
    LANGUAGE sql STABLE
3256
    AS $_$
3257
SELECT oid FROM pg_namespace WHERE nspname = $1
3258
$_$;
3259

    
3260

    
3261
--
3262
-- Name: schema_regexp(regclass); Type: FUNCTION; Schema: util; Owner: -
3263
--
3264

    
3265
CREATE FUNCTION schema_regexp(relation regclass) RETURNS text
3266
    LANGUAGE sql IMMUTABLE
3267
    AS $_$
3268
SELECT util.schema_regexp(schema_anchor := $1)
3269
$_$;
3270

    
3271

    
3272
--
3273
-- Name: schema_regexp(anyelement); Type: FUNCTION; Schema: util; Owner: -
3274
--
3275

    
3276
CREATE FUNCTION schema_regexp(schema_anchor anyelement) RETURNS text
3277
    LANGUAGE sql IMMUTABLE
3278
    AS $_$
3279
SELECT util.str_equality_regexp(util.schema($1))
3280
$_$;
3281

    
3282

    
3283
--
3284
-- Name: schema_rename(text, text); Type: FUNCTION; Schema: util; Owner: -
3285
--
3286

    
3287
CREATE FUNCTION schema_rename(old text, new text) RETURNS void
3288
    LANGUAGE sql
3289
    AS $_$
3290
SELECT util.eval($$ALTER SCHEMA $$||quote_ident($1)||$$ RENAME TO $$||quote_ident($2));
3291
$_$;
3292

    
3293

    
3294
--
3295
-- Name: schema_replace(text, text); Type: FUNCTION; Schema: util; Owner: -
3296
--
3297

    
3298
CREATE FUNCTION schema_replace(replace text, with_ text) RETURNS void
3299
    LANGUAGE plpgsql
3300
    AS $$
3301
BEGIN
3302
	-- don't schema_rm() the schema to keep!
3303
	IF replace = with_ THEN RETURN; END IF;
3304
	
3305
	PERFORM util.schema_rm(replace);
3306
	PERFORM util.schema_rename(with_, replace);
3307
END;
3308
$$;
3309

    
3310

    
3311
--
3312
-- Name: schema_rm(text); Type: FUNCTION; Schema: util; Owner: -
3313
--
3314

    
3315
CREATE FUNCTION schema_rm(schema text) RETURNS void
3316
    LANGUAGE sql
3317
    AS $_$
3318
SELECT util.eval($$DROP SCHEMA IF EXISTS $$||quote_ident($1)||$$ CASCADE$$);
3319
$_$;
3320

    
3321

    
3322
--
3323
-- Name: search_path_append(text); Type: FUNCTION; Schema: util; Owner: -
3324
--
3325

    
3326
CREATE FUNCTION search_path_append(schemas text) RETURNS void
3327
    LANGUAGE sql
3328
    AS $_$
3329
SELECT util.eval(
3330
$$SET search_path TO $$||current_setting('search_path')||$$, $$||$1);
3331
$_$;
3332

    
3333

    
3334
--
3335
-- Name: set_col_names(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3336
--
3337

    
3338
CREATE FUNCTION set_col_names(table_ regclass, names regclass) RETURNS void
3339
    LANGUAGE plpgsql STRICT
3340
    AS $_$
3341
DECLARE
3342
    old text[] = ARRAY(SELECT util.col_names(table_));
3343
    new text[] = ARRAY(SELECT util.map_values(names));
3344
BEGIN
3345
    old = old[1:array_length(new, 1)]; -- truncate to same length
3346
    PERFORM util.eval($$ALTER TABLE $$||$1||$$ RENAME $$||quote_ident(key)
3347
||$$ TO $$||quote_ident(value))
3348
    FROM each(hstore(old, new))
3349
    WHERE value != key -- not same name
3350
    ;
3351
END;
3352
$_$;
3353

    
3354

    
3355
--
3356
-- Name: FUNCTION set_col_names(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3357
--
3358

    
3359
COMMENT ON FUNCTION set_col_names(table_ regclass, names regclass) IS '
3360
idempotent
3361
';
3362

    
3363

    
3364
--
3365
-- Name: set_col_names_with_metadata(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3366
--
3367

    
3368
CREATE FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) RETURNS void
3369
    LANGUAGE plpgsql STRICT
3370
    AS $_$
3371
DECLARE
3372
	row_ util.map;
3373
BEGIN
3374
	-- rename any metadata cols rather than re-adding them with new names
3375
	BEGIN
3376
		PERFORM util.set_col_names(table_, names);
3377
	EXCEPTION
3378
		WHEN array_subscript_error THEN -- selective suppress
3379
			IF SQLERRM LIKE 'arrays must have same bounds' THEN NULL;
3380
				-- metadata cols not yet added
3381
			ELSE RAISE;
3382
			END IF;
3383
	END;
3384
	
3385
	FOR row_ IN EXECUTE $$SELECT * FROM $$||names||$$ WHERE "from" LIKE ':%'$$
3386
	LOOP
3387
		PERFORM util.mk_const_col((table_, row_."to"),
3388
			substring(row_."from" from 2));
3389
	END LOOP;
3390
	
3391
	PERFORM util.set_col_names(table_, names);
3392
END;
3393
$_$;
3394

    
3395

    
3396
--
3397
-- Name: FUNCTION set_col_names_with_metadata(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3398
--
3399

    
3400
COMMENT ON FUNCTION set_col_names_with_metadata(table_ regclass, names regclass) IS '
3401
idempotent.
3402
the metadata mappings must be *last* in the names table.
3403
';
3404

    
3405

    
3406
--
3407
-- Name: set_col_types(regclass, col_cast[]); Type: FUNCTION; Schema: util; Owner: -
3408
--
3409

    
3410
CREATE FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) RETURNS void
3411
    LANGUAGE plpgsql STRICT
3412
    AS $_$
3413
DECLARE
3414
    sql text = $$ALTER TABLE $$||table_||$$
3415
$$||NULLIF(array_to_string(ARRAY(
3416
    SELECT
3417
    $$ALTER COLUMN $$||col_name_sql||$$ TYPE $$||target_type
3418
    ||$$ USING $$||col_name_sql||$$::$$||target_type
3419
    FROM
3420
    (
3421
        SELECT
3422
          quote_ident(col_name) AS col_name_sql
3423
        , util.col_type((table_, col_name)) AS curr_type
3424
        , type AS target_type
3425
        FROM unnest(col_casts)
3426
    ) s
3427
    WHERE curr_type != target_type
3428
), '
3429
, '), '');
3430
BEGIN
3431
    PERFORM util.debug_print_sql(sql);
3432
    EXECUTE COALESCE(sql, '');
3433
END;
3434
$_$;
3435

    
3436

    
3437
--
3438
-- Name: FUNCTION set_col_types(table_ regclass, col_casts col_cast[]); Type: COMMENT; Schema: util; Owner: -
3439
--
3440

    
3441
COMMENT ON FUNCTION set_col_types(table_ regclass, col_casts col_cast[]) IS '
3442
idempotent
3443
';
3444

    
3445

    
3446
--
3447
-- Name: set_comment(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3448
--
3449

    
3450
CREATE FUNCTION set_comment(table_ regclass, comment text) RETURNS void
3451
    LANGUAGE sql
3452
    AS $_$
3453
SELECT util.eval($$COMMENT ON TABLE $$||$1||$$ IS $$||quote_nullable($2))
3454
$_$;
3455

    
3456

    
3457
--
3458
-- Name: set_search_path(text, boolean); Type: FUNCTION; Schema: util; Owner: -
3459
--
3460

    
3461
CREATE FUNCTION set_search_path(search_path text, for_session boolean DEFAULT false) RETURNS void
3462
    LANGUAGE sql
3463
    AS $_$
3464
SELECT util.eval(util.mk_set_search_path($1, $2))
3465
$_$;
3466

    
3467

    
3468
--
3469
-- Name: show_create_view(regclass); Type: FUNCTION; Schema: util; Owner: -
3470
--
3471

    
3472
CREATE FUNCTION show_create_view(view_ regclass) RETURNS text
3473
    LANGUAGE sql STABLE
3474
    AS $_$
3475
SELECT $$CREATE OR REPLACE VIEW $$||$1||$$ AS $$||pg_get_viewdef($1)||$$;
3476
$$||util.show_grants_for($1)
3477
$_$;
3478

    
3479

    
3480
--
3481
-- Name: show_grants_for(regclass); Type: FUNCTION; Schema: util; Owner: -
3482
--
3483

    
3484
CREATE FUNCTION show_grants_for(table_ regclass) RETURNS text
3485
    LANGUAGE sql STABLE
3486
    AS $_$
3487
SELECT string_agg(cmd, '')
3488
FROM
3489
(
3490
	SELECT (CASE WHEN has_table_privilege(user_, $1, 'SELECT') THEN
3491
$$GRANT SELECT ON TABLE $$||$1||$$ TO $$||quote_ident(user_)||$$;
3492
$$ ELSE '' END) AS cmd
3493
	FROM util.grants_users() f (user_)
3494
) s
3495
$_$;
3496

    
3497

    
3498
--
3499
-- Name: show_relations_like(text, text, character[]); Type: FUNCTION; Schema: util; Owner: -
3500
--
3501

    
3502
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
3503
    LANGUAGE sql STABLE
3504
    AS $_$
3505
SELECT oid FROM pg_class
3506
WHERE relkind = ANY($3) AND relname ~ $1
3507
AND util.schema_matches(util.schema(relnamespace), $2)
3508
ORDER BY relname
3509
$_$;
3510

    
3511

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

    
3516
CREATE FUNCTION show_types_like(name_regexp text DEFAULT ''::text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regtype
3517
    LANGUAGE sql STABLE
3518
    AS $_$
3519
SELECT oid
3520
FROM pg_type
3521
WHERE typname ~ $1 AND util.schema_matches(util.schema(typnamespace), $2)
3522
ORDER BY typname
3523
$_$;
3524

    
3525

    
3526
--
3527
-- Name: show_views_like(text, text); Type: FUNCTION; Schema: util; Owner: -
3528
--
3529

    
3530
CREATE FUNCTION show_views_like(name_regexp text, schema_regexp text DEFAULT ''::text) RETURNS SETOF regclass
3531
    LANGUAGE sql STABLE
3532
    AS $_$
3533
SELECT * FROM util.show_relations_like($1, $2, ARRAY['v'])
3534
$_$;
3535

    
3536

    
3537
--
3538
-- Name: str_equality_regexp(text); Type: FUNCTION; Schema: util; Owner: -
3539
--
3540

    
3541
CREATE FUNCTION str_equality_regexp(literal text) RETURNS text
3542
    LANGUAGE sql IMMUTABLE
3543
    AS $_$
3544
SELECT '^'||util.regexp_quote($1)||'$'
3545
$_$;
3546

    
3547

    
3548
--
3549
-- Name: table2hstore(regclass); Type: FUNCTION; Schema: util; Owner: -
3550
--
3551

    
3552
CREATE FUNCTION table2hstore(table_ regclass) RETURNS hstore
3553
    LANGUAGE plpgsql STABLE STRICT
3554
    AS $_$
3555
DECLARE
3556
    hstore hstore;
3557
BEGIN
3558
    EXECUTE $$SELECT hstore(ARRAY(SELECT unnest(ARRAY["from", "to"]) FROM $$||
3559
        table_||$$))$$ INTO STRICT hstore;
3560
    RETURN hstore;
3561
END;
3562
$_$;
3563

    
3564

    
3565
--
3566
-- Name: table_flag__get(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3567
--
3568

    
3569
CREATE FUNCTION table_flag__get(table_ regclass, flag text) RETURNS boolean
3570
    LANGUAGE sql STABLE
3571
    AS $_$
3572
SELECT COUNT(*) > 0 FROM pg_constraint
3573
WHERE conrelid = $1 AND contype = 'c' AND conname = $2
3574
$_$;
3575

    
3576

    
3577
--
3578
-- Name: FUNCTION table_flag__get(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3579
--
3580

    
3581
COMMENT ON FUNCTION table_flag__get(table_ regclass, flag text) IS '
3582
gets whether a status flag is set by the presence of a table constraint
3583
';
3584

    
3585

    
3586
--
3587
-- Name: table_flag__set(regclass, text); Type: FUNCTION; Schema: util; Owner: -
3588
--
3589

    
3590
CREATE FUNCTION table_flag__set(table_ regclass, flag text) RETURNS void
3591
    LANGUAGE sql
3592
    AS $_$
3593
SELECT util.create_if_not_exists($$ALTER TABLE $$||$1||$$ ADD CONSTRAINT $$
3594
||quote_ident($2)||$$ CHECK (true)$$)
3595
$_$;
3596

    
3597

    
3598
--
3599
-- Name: FUNCTION table_flag__set(table_ regclass, flag text); Type: COMMENT; Schema: util; Owner: -
3600
--
3601

    
3602
COMMENT ON FUNCTION table_flag__set(table_ regclass, flag text) IS '
3603
stores a status flag by the presence of a table constraint.
3604
idempotent.
3605
';
3606

    
3607

    
3608
--
3609
-- Name: table_nulls_mapped__get(regclass); Type: FUNCTION; Schema: util; Owner: -
3610
--
3611

    
3612
CREATE FUNCTION table_nulls_mapped__get(table_ regclass) RETURNS boolean
3613
    LANGUAGE sql STABLE
3614
    AS $_$
3615
SELECT util.table_flag__get($1, 'nulls_mapped')
3616
$_$;
3617

    
3618

    
3619
--
3620
-- Name: FUNCTION table_nulls_mapped__get(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3621
--
3622

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

    
3627

    
3628
--
3629
-- Name: table_nulls_mapped__set(regclass); Type: FUNCTION; Schema: util; Owner: -
3630
--
3631

    
3632
CREATE FUNCTION table_nulls_mapped__set(table_ regclass) RETURNS void
3633
    LANGUAGE sql
3634
    AS $_$
3635
SELECT util.table_flag__set($1, 'nulls_mapped')
3636
$_$;
3637

    
3638

    
3639
--
3640
-- Name: FUNCTION table_nulls_mapped__set(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3641
--
3642

    
3643
COMMENT ON FUNCTION table_nulls_mapped__set(table_ regclass) IS '
3644
sets that a table''s NULL-equivalent strings have been replaced with NULL.
3645
idempotent.
3646
';
3647

    
3648

    
3649
--
3650
-- Name: to_freq(regclass); Type: FUNCTION; Schema: util; Owner: -
3651
--
3652

    
3653
CREATE FUNCTION to_freq(table_ regclass) RETURNS void
3654
    LANGUAGE sql
3655
    AS $_$
3656
-- save data before truncating main table
3657
SELECT util.copy_types_and_data($1, 'pg_temp.__copy');
3658

    
3659
-- repopulate main table w/ copies column
3660
SELECT util.truncate($1);
3661
SELECT util.eval($$ALTER TABLE $$||$1||$$ ADD COLUMN copies bigint NOT NULL$$);
3662
SELECT util.populate_table($1, $$
3663
SELECT (table_).*, copies
3664
FROM (
3665
	SELECT table_, COUNT(*) AS copies
3666
	FROM pg_temp.__copy table_
3667
	GROUP BY table_
3668
) s
3669
$$);
3670

    
3671
-- delete temp table so it doesn't stay around until end of connection
3672
SELECT util.drop_table('pg_temp.__copy');
3673
$_$;
3674

    
3675

    
3676
--
3677
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: util; Owner: -
3678
--
3679

    
3680
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
3681
    LANGUAGE plpgsql STRICT
3682
    AS $_$
3683
DECLARE
3684
    row record;
3685
BEGIN
3686
    FOR row IN SELECT * FROM util.col_global_names(table_::text::regtype)
3687
    LOOP
3688
        IF row.global_name != row.name THEN
3689
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
3690
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
3691
        END IF;
3692
    END LOOP;
3693
END;
3694
$_$;
3695

    
3696

    
3697
--
3698
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3699
--
3700

    
3701
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS '
3702
idempotent
3703
';
3704

    
3705

    
3706
--
3707
-- Name: trim(regclass, regclass); Type: FUNCTION; Schema: util; Owner: -
3708
--
3709

    
3710
CREATE FUNCTION "trim"(table_ regclass, names regclass) RETURNS void
3711
    LANGUAGE sql
3712
    AS $_$
3713
SELECT util.drop_column(($1, col)) FROM util.added_cols($1, $2) f (col);
3714
SELECT NULL::void; -- don't fold away functions called in previous query
3715
$_$;
3716

    
3717

    
3718
--
3719
-- Name: FUNCTION "trim"(table_ regclass, names regclass); Type: COMMENT; Schema: util; Owner: -
3720
--
3721

    
3722
COMMENT ON FUNCTION "trim"(table_ regclass, names regclass) IS '
3723
trims table_ to include only columns in the original data.
3724
idempotent.
3725
';
3726

    
3727

    
3728
--
3729
-- Name: truncate(regclass); Type: FUNCTION; Schema: util; Owner: -
3730
--
3731

    
3732
CREATE FUNCTION truncate(table_ regclass) RETURNS void
3733
    LANGUAGE plpgsql STRICT
3734
    AS $_$
3735
BEGIN
3736
    EXECUTE $$TRUNCATE $$||table_||$$ CASCADE$$;
3737
END;
3738
$_$;
3739

    
3740

    
3741
--
3742
-- Name: FUNCTION truncate(table_ regclass); Type: COMMENT; Schema: util; Owner: -
3743
--
3744

    
3745
COMMENT ON FUNCTION truncate(table_ regclass) IS '
3746
idempotent
3747
';
3748

    
3749

    
3750
--
3751
-- Name: truncated_prefixed_name_regexp(text, integer); Type: FUNCTION; Schema: util; Owner: -
3752
--
3753

    
3754
CREATE FUNCTION truncated_prefixed_name_regexp(name text, max_prefix_len integer) RETURNS text
3755
    LANGUAGE sql IMMUTABLE
3756
    AS $_$
3757
SELECT '^(.*)'||util._if(util.name_was_truncated($1, $2),
3758
util.regexp_quote(util.rtrim_n($1, $2))||'.*', util.regexp_quote($1)) ||'$'
3759
$_$;
3760

    
3761

    
3762
--
3763
-- Name: try_create(text); Type: FUNCTION; Schema: util; Owner: -
3764
--
3765

    
3766
CREATE FUNCTION try_create(sql text) RETURNS void
3767
    LANGUAGE plpgsql STRICT
3768
    AS $$
3769
BEGIN
3770
	PERFORM util.eval(sql);
3771
EXCEPTION
3772
WHEN   not_null_violation
3773
		/* trying to add NOT NULL column to parent table, which cascades to
3774
		child table whose values for the new column will be NULL */
3775
	OR wrong_object_type -- trying to alter a view's columns
3776
	OR undefined_column
3777
	OR duplicate_column
3778
THEN NULL;
3779
END;
3780
$$;
3781

    
3782

    
3783
--
3784
-- Name: FUNCTION try_create(sql text); Type: COMMENT; Schema: util; Owner: -
3785
--
3786

    
3787
COMMENT ON FUNCTION try_create(sql text) IS '
3788
idempotent
3789
';
3790

    
3791

    
3792
--
3793
-- Name: try_mk_derived_col(col_ref, text); Type: FUNCTION; Schema: util; Owner: -
3794
--
3795

    
3796
CREATE FUNCTION try_mk_derived_col(col col_ref, expr text) RETURNS void
3797
    LANGUAGE sql
3798
    AS $_$
3799
SELECT util.try_create($$SELECT util.mk_derived_col($$||quote_literal($1)||$$, $$||quote_literal($2)||$$)$$)
3800
$_$;
3801

    
3802

    
3803
--
3804
-- Name: FUNCTION try_mk_derived_col(col col_ref, expr text); Type: COMMENT; Schema: util; Owner: -
3805
--
3806

    
3807
COMMENT ON FUNCTION try_mk_derived_col(col col_ref, expr text) IS '
3808
idempotent
3809
';
3810

    
3811

    
3812
--
3813
-- Name: type_qual(anyelement); Type: FUNCTION; Schema: util; Owner: -
3814
--
3815

    
3816
CREATE FUNCTION type_qual(value anyelement) RETURNS text
3817
    LANGUAGE sql IMMUTABLE
3818
    AS $_$
3819
SELECT CASE WHEN $1 IS NULL THEN '' ELSE $$ NOT NULL$$ END
3820
$_$;
3821

    
3822

    
3823
--
3824
-- Name: FUNCTION type_qual(value anyelement); Type: COMMENT; Schema: util; Owner: -
3825
--
3826

    
3827
COMMENT ON FUNCTION type_qual(value anyelement) IS '
3828
a type''s NOT NULL qualifier
3829
';
3830

    
3831

    
3832
--
3833
-- Name: typed_cols(regtype); Type: FUNCTION; Schema: util; Owner: -
3834
--
3835

    
3836
CREATE FUNCTION typed_cols(type regtype) RETURNS SETOF col_cast
3837
    LANGUAGE sql STABLE
3838
    AS $_$
3839
SELECT (attname::text, atttypid)::util.col_cast
3840
FROM pg_attribute
3841
WHERE attrelid = $1::text::regclass AND attnum >= 1 AND NOT attisdropped
3842
ORDER BY attnum
3843
$_$;
3844

    
3845

    
3846
--
3847
-- Name: typeof(anyelement); Type: FUNCTION; Schema: util; Owner: -
3848
--
3849

    
3850
CREATE FUNCTION typeof(value anyelement) RETURNS text
3851
    LANGUAGE sql IMMUTABLE
3852
    AS $_$
3853
SELECT util.qual_name(pg_typeof($1))
3854
$_$;
3855

    
3856

    
3857
--
3858
-- Name: typeof(text, regtype); Type: FUNCTION; Schema: util; Owner: -
3859
--
3860

    
3861
CREATE FUNCTION typeof(expr text, table_ regtype DEFAULT NULL::regtype) RETURNS regtype
3862
    LANGUAGE plpgsql STABLE
3863
    AS $_$
3864
DECLARE
3865
    type regtype;
3866
BEGIN
3867
    EXECUTE $$SELECT pg_typeof($$||expr||$$)$$||
3868
COALESCE($$ FROM (SELECT (NULL::$$||table_||$$).*) _s$$, '') INTO STRICT type;
3869
    RETURN type;
3870
END;
3871
$_$;
3872

    
3873

    
3874
--
3875
-- Name: use_schema(anyelement); Type: FUNCTION; Schema: util; Owner: -
3876
--
3877

    
3878
CREATE FUNCTION use_schema(schema_anchor anyelement) RETURNS void
3879
    LANGUAGE sql
3880
    AS $_$
3881
SELECT util.set_search_path(util.mk_search_path(util.schema($1)))
3882
$_$;
3883

    
3884

    
3885
--
3886
-- Name: FUNCTION use_schema(schema_anchor anyelement); Type: COMMENT; Schema: util; Owner: -
3887
--
3888

    
3889
COMMENT ON FUNCTION use_schema(schema_anchor anyelement) IS '
3890
auto-appends util to the search_path to enable use of util operators
3891
';
3892

    
3893

    
3894
--
3895
-- Name: all_same(anyelement); Type: AGGREGATE; Schema: util; Owner: -
3896
--
3897

    
3898
CREATE AGGREGATE all_same(anyelement) (
3899
    SFUNC = all_same_transform,
3900
    STYPE = anyarray,
3901
    FINALFUNC = all_same_final
3902
);
3903

    
3904

    
3905
--
3906
-- Name: AGGREGATE all_same(anyelement); Type: COMMENT; Schema: util; Owner: -
3907
--
3908

    
3909
COMMENT ON AGGREGATE all_same(anyelement) IS '
3910
includes NULLs in comparison
3911
';
3912

    
3913

    
3914
--
3915
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: util; Owner: -
3916
--
3917

    
3918
CREATE AGGREGATE join_strs(text, text) (
3919
    SFUNC = join_strs_transform,
3920
    STYPE = text
3921
);
3922

    
3923

    
3924
--
3925
-- Name: %==; Type: OPERATOR; Schema: util; Owner: -
3926
--
3927

    
3928
CREATE OPERATOR %== (
3929
    PROCEDURE = "%==",
3930
    LEFTARG = anyelement,
3931
    RIGHTARG = anyelement
3932
);
3933

    
3934

    
3935
--
3936
-- Name: OPERATOR %== (anyelement, anyelement); Type: COMMENT; Schema: util; Owner: -
3937
--
3938

    
3939
COMMENT ON OPERATOR %== (anyelement, anyelement) IS '
3940
returns whether the map-keys of the compared values are the same
3941
(mnemonic: % is the Perl symbol for a hash map)
3942

    
3943
should be overridden for types that store both keys and values
3944

    
3945
used in a FULL JOIN to select which columns to join on
3946
';
3947

    
3948

    
3949
--
3950
-- Name: ->; Type: OPERATOR; Schema: util; Owner: -
3951
--
3952

    
3953
CREATE OPERATOR -> (
3954
    PROCEDURE = map_get,
3955
    LEFTARG = regclass,
3956
    RIGHTARG = text
3957
);
3958

    
3959

    
3960
--
3961
-- Name: =>; Type: OPERATOR; Schema: util; Owner: -
3962
--
3963

    
3964
CREATE OPERATOR => (
3965
    PROCEDURE = hstore,
3966
    LEFTARG = text[],
3967
    RIGHTARG = text
3968
);
3969

    
3970

    
3971
--
3972
-- Name: OPERATOR => (text[], text); Type: COMMENT; Schema: util; Owner: -
3973
--
3974

    
3975
COMMENT ON OPERATOR => (text[], text) IS '
3976
usage: array[''key1'', ...]::text[] => ''value''
3977
';
3978

    
3979

    
3980
--
3981
-- Name: ?*>=; Type: OPERATOR; Schema: util; Owner: -
3982
--
3983

    
3984
CREATE OPERATOR ?*>= (
3985
    PROCEDURE = is_populated_more_often_than,
3986
    LEFTARG = anyelement,
3987
    RIGHTARG = anyelement
3988
);
3989

    
3990

    
3991
--
3992
-- Name: ?>=; Type: OPERATOR; Schema: util; Owner: -
3993
--
3994

    
3995
CREATE OPERATOR ?>= (
3996
    PROCEDURE = is_more_complete_than,
3997
    LEFTARG = anyelement,
3998
    RIGHTARG = anyelement
3999
);
4000

    
4001

    
4002
--
4003
-- Name: ||%; Type: OPERATOR; Schema: util; Owner: -
4004
--
4005

    
4006
CREATE OPERATOR ||% (
4007
    PROCEDURE = concat_esc,
4008
    LEFTARG = text,
4009
    RIGHTARG = text
4010
);
4011

    
4012

    
4013
--
4014
-- Name: OPERATOR ||% (text, text); Type: COMMENT; Schema: util; Owner: -
4015
--
4016

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

    
4021

    
4022
--
4023
-- Name: map; Type: TABLE; Schema: util; Owner: -; Tablespace: 
4024
--
4025

    
4026
CREATE TABLE map (
4027
    "from" text NOT NULL,
4028
    "to" text,
4029
    filter text,
4030
    notes text
4031
);
4032

    
4033

    
4034
--
4035
-- Data for Name: explain; Type: TABLE DATA; Schema: util; Owner: -
4036
--
4037

    
4038

    
4039

    
4040
--
4041
-- Data for Name: map; Type: TABLE DATA; Schema: util; Owner: -
4042
--
4043

    
4044

    
4045

    
4046
--
4047
-- Name: map__unique__from; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4048
--
4049

    
4050
ALTER TABLE ONLY map
4051
    ADD CONSTRAINT map__unique__from UNIQUE ("from");
4052

    
4053

    
4054
--
4055
-- Name: map__unique__to; Type: CONSTRAINT; Schema: util; Owner: -; Tablespace: 
4056
--
4057

    
4058
ALTER TABLE ONLY map
4059
    ADD CONSTRAINT map__unique__to UNIQUE ("to");
4060

    
4061

    
4062
--
4063
-- Name: map_filter_insert; Type: TRIGGER; Schema: util; Owner: -
4064
--
4065

    
4066
CREATE TRIGGER map_filter_insert BEFORE INSERT ON map FOR EACH ROW EXECUTE PROCEDURE map_filter_insert();
4067

    
4068

    
4069
--
4070
-- PostgreSQL database dump complete
4071
--
4072

    
(19-19/29)