Project

General

Profile

1 2094 aaronmk
--
2
-- PostgreSQL database dump
3
--
4
5
SET statement_timeout = 0;
6
SET client_encoding = 'UTF8';
7 6213 aaronmk
SET standard_conforming_strings = on;
8 2094 aaronmk
SET check_function_bodies = false;
9
SET client_min_messages = warning;
10
11
--
12
-- Name: functions; Type: SCHEMA; Schema: -; Owner: -
13
--
14
15
CREATE SCHEMA functions;
16
17
18 4982 aaronmk
--
19
-- Name: SCHEMA functions; Type: COMMENT; Schema: -; Owner: -
20
--
21
22
COMMENT ON SCHEMA functions IS 'IMPORTANT: Functions must always return NULL in place of '''' (the empty string). This ensures that empty strings do not find their way into VegBIEN.';
23
24
25 2107 aaronmk
SET search_path = functions, pg_catalog;
26
27 2094 aaronmk
--
28 7673 aaronmk
-- Name: compass_dir; Type: TYPE; Schema: functions; Owner: -
29
--
30
31
CREATE TYPE compass_dir AS ENUM (
32
    'N',
33
    'E',
34
    'S',
35
    'W'
36
);
37
38
39
--
40 2610 aaronmk
-- Name: datatype; Type: TYPE; Schema: functions; Owner: -
41
--
42
43
CREATE TYPE datatype AS ENUM (
44
    'str',
45
    'float'
46
);
47
48
49
--
50 4501 aaronmk
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
51 2596 aaronmk
--
52
53 4501 aaronmk
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
54 3422 aaronmk
    LANGUAGE sql IMMUTABLE
55
    AS $_$
56 4501 aaronmk
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
57 3422 aaronmk
$_$;
58
59
60
--
61 5956 aaronmk
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: functions; Owner: -
62 5937 aaronmk
--
63
64 5956 aaronmk
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
65 5937 aaronmk
    LANGUAGE sql IMMUTABLE
66
    AS $_$
67
SELECT bool_and(value)
68
FROM
69
(VALUES
70
      ($1)
71
    , ($2)
72 5956 aaronmk
    , ($3)
73
    , ($4)
74
    , ($5)
75 5937 aaronmk
)
76
AS v (value)
77
$_$;
78
79
80
--
81 5956 aaronmk
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: functions; Owner: -
82 5937 aaronmk
--
83
84 6437 aaronmk
COMMENT ON FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_and() ignores NULL values, while AND combines them with the other values to potentially convert true to NULL. AND should be used with required fields, and _and() with optional fields.';
85 5937 aaronmk
86
87
--
88 7704 aaronmk
-- Name: _avg(double precision, double precision, double precision, double precision, double precision); Type: FUNCTION; Schema: functions; Owner: -
89
--
90
91
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
92
    LANGUAGE sql IMMUTABLE
93
    AS $_$
94
SELECT avg(value)
95
FROM
96
(VALUES
97
      ($1)
98
    , ($2)
99
    , ($3)
100
    , ($4)
101
    , ($5)
102
)
103
AS v (value)
104
$_$;
105
106
107
--
108 7679 aaronmk
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: functions; Owner: -
109
--
110
111
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
112
    LANGUAGE sql IMMUTABLE STRICT
113
    AS $_$
114
SELECT (g[1]||'1')::integer*functions._dms_to_dd(deg := g[2]::double precision, min := g[3]::double precision, sec := g[4]::double precision, dir := g[5]::functions.compass_dir)
115 7698 aaronmk
FROM
116
(
117
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
118
    UNION ALL
119 7702 aaronmk
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
120
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
121 7698 aaronmk
)
122
matches (g)
123 7679 aaronmk
$_$;
124
125
126
--
127 7674 aaronmk
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: functions; Owner: -
128 7672 aaronmk
--
129
130 7674 aaronmk
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
131 7672 aaronmk
    LANGUAGE sql IMMUTABLE
132
    AS $_$
133 7678 aaronmk
SELECT sum(value)*COALESCE(functions._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
134 7672 aaronmk
FROM
135
(VALUES
136 7677 aaronmk
      ($1)
137 7672 aaronmk
    , ($2/60)
138
    , ($3/60/60)
139
)
140
AS v (value)
141
$_$;
142
143
144
--
145 7723 aaronmk
-- Name: _dms_to_dd(text, text, text, text); Type: FUNCTION; Schema: functions; Owner: -
146
--
147
148
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
149
    LANGUAGE sql IMMUTABLE
150
    AS $_$
151
SELECT functions._dms_to_dd($1::double precision, $2::double precision, $3::double precision, $4::functions.compass_dir)
152
$_$;
153
154
155
--
156 4142 aaronmk
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
157
--
158
159
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
160
    LANGUAGE sql IMMUTABLE
161
    AS $_$
162
SELECT $1 = $2
163
$_$;
164
165
166
--
167 7396 aaronmk
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: functions; Owner: -
168
--
169
170
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
171
    LANGUAGE sql IMMUTABLE
172
    AS $_$
173
-- Fix dates after threshold date
174
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
175
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
176
$_$;
177
178
179
--
180 4147 aaronmk
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
181
--
182
183
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
184
    LANGUAGE sql IMMUTABLE
185
    AS $_$
186
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
187
$_$;
188
189
190
--
191
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
192
--
193
194
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
195
    LANGUAGE sql IMMUTABLE
196
    AS $_$
197
SELECT functions._if($1 != '', $2, $3)
198
$_$;
199
200
201
--
202 4325 aaronmk
-- Name: _join(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
203
--
204
205
CREATE FUNCTION _join("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
206
    LANGUAGE sql IMMUTABLE
207
    AS $_$
208 7848 aaronmk
SELECT NULLIF(concat_ws('; ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
209 4325 aaronmk
$_$;
210
211
212
--
213 5009 aaronmk
-- Name: _join_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
214
--
215
216
CREATE FUNCTION _join_words("0" anyelement DEFAULT NULL::unknown, "1" anyelement DEFAULT NULL::unknown, "2" anyelement DEFAULT NULL::unknown, "3" anyelement DEFAULT NULL::unknown, "4" anyelement DEFAULT NULL::unknown, "5" anyelement DEFAULT NULL::unknown, "6" anyelement DEFAULT NULL::unknown, "7" anyelement DEFAULT NULL::unknown, "8" anyelement DEFAULT NULL::unknown, "9" anyelement DEFAULT NULL::unknown) RETURNS anyelement
217
    LANGUAGE sql IMMUTABLE
218
    AS $_$
219 7848 aaronmk
SELECT NULLIF(concat_ws(' ', $1, $2, $3, $4, $5, $6, $7, $8, $9, $10), '')
220 5009 aaronmk
$_$;
221
222
223
--
224 4683 aaronmk
-- Name: _label(anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
225 3422 aaronmk
--
226
227 4683 aaronmk
CREATE FUNCTION _label(label anyelement, value anyelement) RETURNS anyelement
228 4682 aaronmk
    LANGUAGE sql IMMUTABLE
229
    AS $_$
230
SELECT coalesce($1 || ': ', '') || $2
231
$_$;
232 2596 aaronmk
233
234
--
235 6222 aaronmk
-- Name: _map(hstore, text); Type: FUNCTION; Schema: functions; Owner: -
236
--
237
238
CREATE FUNCTION _map(map hstore, value text) RETURNS text
239 7820 aaronmk
    LANGUAGE plpgsql IMMUTABLE STRICT
240 6222 aaronmk
    AS $$
241
DECLARE
242 6271 aaronmk
    match text := map -> value;
243 6222 aaronmk
BEGIN
244 6271 aaronmk
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
245
        match := map -> '*'; -- use default entry
246
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
247
        END IF;
248
    END IF;
249
250
    -- Interpret result
251 6243 aaronmk
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
252
    ELSIF match = '*' THEN RETURN value;
253
    ELSE RETURN match;
254 6222 aaronmk
    END IF;
255
END;
256
$$;
257
258
259
--
260 5408 aaronmk
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
261
--
262
263
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
264
    LANGUAGE sql IMMUTABLE
265
    AS $_$
266 7289 aaronmk
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
267 5408 aaronmk
$_$;
268
269
270
--
271 4150 aaronmk
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
272 2940 aaronmk
--
273
274 4150 aaronmk
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
275 2940 aaronmk
    LANGUAGE sql IMMUTABLE
276
    AS $_$
277 4053 aaronmk
SELECT functions.join_strs(value, '; ')
278 2940 aaronmk
FROM
279
(
280
    SELECT *
281
    FROM
282
    (
283
        SELECT
284
        DISTINCT ON (value)
285
        *
286
        FROM
287
        (VALUES
288 4012 aaronmk
              (1, $1)
289
            , (2, $2)
290
            , (3, $3)
291
            , (4, $4)
292
            , (5, $5)
293
            , (6, $6)
294
            , (7, $7)
295
            , (8, $8)
296
            , (9, $9)
297
            , (10, $10)
298 2940 aaronmk
        )
299
        AS v (sort_order, value)
300 4011 aaronmk
        WHERE value IS NOT NULL
301 2940 aaronmk
    )
302
    AS v
303
    ORDER BY sort_order
304
)
305
AS v
306
$_$;
307
308
309
--
310 7140 aaronmk
-- Name: _merge_prefix(text, text); Type: FUNCTION; Schema: functions; Owner: -
311
--
312
313
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
314
    LANGUAGE sql IMMUTABLE
315
    AS $_$
316
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
317
$_$;
318
319
320
--
321 6354 aaronmk
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
322
--
323
324
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
325
    LANGUAGE sql IMMUTABLE
326
    AS $_$
327
SELECT functions.join_strs(value, ' ')
328
FROM
329
(
330
    SELECT *
331
    FROM
332
    (
333
        SELECT
334
        DISTINCT ON (value)
335
        *
336
        FROM
337
        (VALUES
338
              (1, $1)
339
            , (2, $2)
340
            , (3, $3)
341
            , (4, $4)
342
            , (5, $5)
343
            , (6, $6)
344
            , (7, $7)
345
            , (8, $8)
346
            , (9, $9)
347
            , (10, $10)
348
        )
349
        AS v (sort_order, value)
350
        WHERE value IS NOT NULL
351
    )
352
    AS v
353
    ORDER BY sort_order
354
)
355
AS v
356
$_$;
357
358
359
--
360 5408 aaronmk
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
361
--
362
363
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
364
    LANGUAGE sql IMMUTABLE
365
    AS $_$
366 7289 aaronmk
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
367 5408 aaronmk
$_$;
368
369
370
--
371 6316 aaronmk
-- Name: _not(boolean); Type: FUNCTION; Schema: functions; Owner: -
372
--
373
374
CREATE FUNCTION _not(value boolean) RETURNS boolean
375
    LANGUAGE sql IMMUTABLE STRICT
376
    AS $_$
377
SELECT NOT $1
378
$_$;
379
380
381
--
382 7104 aaronmk
-- Name: _now(); Type: FUNCTION; Schema: functions; Owner: -
383
--
384
385
CREATE FUNCTION _now() RETURNS timestamp with time zone
386
    LANGUAGE sql STABLE
387
    AS $$
388
SELECT now()
389
$$;
390
391
392
--
393 4475 aaronmk
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: functions; Owner: -
394 2949 aaronmk
--
395
396 4475 aaronmk
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
397 2949 aaronmk
    LANGUAGE plpgsql IMMUTABLE
398
    AS $$
399
DECLARE
400
    type functions.datatype NOT NULL := type; -- add NOT NULL
401
BEGIN
402 4475 aaronmk
    IF type = 'str' THEN RETURN nullif(value::text, "null");
403 2722 aaronmk
    -- Invalid value is ignored, but invalid null value generates error
404 2949 aaronmk
    ELSIF type = 'float' THEN
405 2722 aaronmk
        DECLARE
406
            -- Outside the try block so that invalid null value generates error
407 2949 aaronmk
            "null" double precision := "null"::double precision;
408 2722 aaronmk
        BEGIN
409 2949 aaronmk
            RETURN nullif(value::double precision, "null");
410 2722 aaronmk
        EXCEPTION
411 2949 aaronmk
            WHEN data_exception THEN RETURN value; -- ignore invalid value
412 2722 aaronmk
        END;
413 2610 aaronmk
    END IF;
414
END;
415
$$;
416
417
418
--
419 4479 aaronmk
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: functions; Owner: -
420
--
421
422
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
423
    LANGUAGE sql IMMUTABLE
424
    AS $_$
425
SELECT functions."_nullIf"($1, $2, $3::functions.datatype)
426
$_$;
427
428
429
--
430 6355 aaronmk
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: functions; Owner: -
431
--
432
433
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
434
    LANGUAGE sql IMMUTABLE
435
    AS $_$
436
SELECT bool_or(value)
437
FROM
438
(VALUES
439
      ($1)
440
    , ($2)
441
    , ($3)
442
    , ($4)
443
    , ($5)
444
)
445
AS v (value)
446
$_$;
447
448
449
--
450 6437 aaronmk
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: functions; Owner: -
451
--
452
453
COMMENT ON FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean) IS '_or() ignores NULL values, while OR combines them with the other values to potentially convert false to NULL. OR should be used with required fields, and _or() with optional fields.';
454
455
456
--
457 7706 aaronmk
-- Name: _range(double precision, double precision); Type: FUNCTION; Schema: functions; Owner: -
458
--
459
460
CREATE FUNCTION _range("from" double precision DEFAULT NULL::double precision, "to" double precision DEFAULT NULL::double precision) RETURNS double precision
461
    LANGUAGE sql IMMUTABLE
462
    AS $_$
463
SELECT $2 - $1
464
$_$;
465
466
467
--
468 6793 aaronmk
-- Name: _split(text, text); Type: FUNCTION; Schema: functions; Owner: -
469
--
470
471
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
472
    LANGUAGE sql IMMUTABLE STRICT
473
    AS $_$
474
SELECT regexp_split_to_table($1, $2)
475
$_$;
476
477
478
--
479 8104 aaronmk
-- Name: cluster_index(regclass); Type: FUNCTION; Schema: functions; Owner: -
480
--
481
482
CREATE FUNCTION cluster_index(table_ regclass) RETURNS regclass
483
    LANGUAGE sql STABLE STRICT
484
    AS $_$
485
SELECT indexrelid FROM pg_index WHERE indrelid = $1 AND indisclustered
486
$_$;
487
488
489
--
490 8084 aaronmk
-- Name: col_global_names(regtype); Type: FUNCTION; Schema: functions; Owner: -
491
--
492
493
CREATE FUNCTION col_global_names(type regtype, OUT name text, OUT global_name text) RETURNS SETOF record
494 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
495 8084 aaronmk
    AS $$
496
DECLARE
497
    prefix text := functions.name(type)||'.';
498
BEGIN
499
    RETURN QUERY
500 8096 aaronmk
        SELECT name_, (CASE WHEN functions.contains(search_for:='.', in_str:=name_) THEN '' ELSE prefix END)||name_
501 8087 aaronmk
        FROM functions.col_names(type) f (name_);
502 8084 aaronmk
END;
503
$$;
504
505
506
--
507 8082 aaronmk
-- Name: col_names(regtype); Type: FUNCTION; Schema: functions; Owner: -
508
--
509
510
CREATE FUNCTION col_names(type regtype) RETURNS SETOF text
511 8097 aaronmk
    LANGUAGE plpgsql STABLE STRICT
512 8082 aaronmk
    AS $_$
513
BEGIN
514
    RETURN QUERY EXECUTE $$SELECT skeys(hstore(NULL::$$||type||$$))$$;
515
END;
516
$_$;
517
518
519
--
520 8095 aaronmk
-- Name: contains(text, text); Type: FUNCTION; Schema: functions; Owner: -
521
--
522
523
CREATE FUNCTION contains(search_for text, in_str text) RETURNS boolean
524
    LANGUAGE sql IMMUTABLE STRICT
525
    AS $_$
526
SELECT position($1 in $2) > 0 /*1-based offset*/
527
$_$;
528
529
530
--
531 8094 aaronmk
-- Name: create_if_not_exists(text); Type: FUNCTION; Schema: functions; Owner: -
532
--
533
534
CREATE FUNCTION create_if_not_exists(sql text) RETURNS void
535
    LANGUAGE plpgsql STRICT
536
    AS $$
537
BEGIN
538
    EXECUTE sql;
539
EXCEPTION
540 8103 aaronmk
    WHEN duplicate_table  THEN NULL;
541
    WHEN duplicate_column THEN NULL;
542 8094 aaronmk
END;
543
$$;
544
545
546
--
547
-- Name: FUNCTION create_if_not_exists(sql text); Type: COMMENT; Schema: functions; Owner: -
548
--
549
550
COMMENT ON FUNCTION create_if_not_exists(sql text) IS 'idempotent';
551
552
553
--
554 8086 aaronmk
-- Name: ensure_prefix(text, text); Type: FUNCTION; Schema: functions; Owner: -
555
--
556
557
CREATE FUNCTION ensure_prefix(prefix text, str text) RETURNS text
558 8097 aaronmk
    LANGUAGE sql STABLE STRICT
559 8086 aaronmk
    AS $_$
560
SELECT (CASE WHEN functions.has_prefix($1, $2) THEN $2 ELSE $1||$2 END)
561
$_$;
562
563
564
--
565 8085 aaronmk
-- Name: has_prefix(text, text); Type: FUNCTION; Schema: functions; Owner: -
566
--
567
568
CREATE FUNCTION has_prefix(prefix text, str text) RETURNS boolean
569
    LANGUAGE sql IMMUTABLE STRICT
570
    AS $_$
571
SELECT substring($2 for length($1)) = $1
572
$_$;
573
574
575
--
576 4052 aaronmk
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: functions; Owner: -
577 4009 aaronmk
--
578
579 4053 aaronmk
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
580 4054 aaronmk
    LANGUAGE sql IMMUTABLE STRICT
581 4009 aaronmk
    AS $_$
582 4054 aaronmk
SELECT $1 || $3 || $2
583 2595 aaronmk
$_$;
584
585
586
--
587 8083 aaronmk
-- Name: name(regtype); Type: FUNCTION; Schema: functions; Owner: -
588
--
589
590
CREATE FUNCTION name(type regtype) RETURNS text
591 8097 aaronmk
    LANGUAGE sql STABLE STRICT
592 8083 aaronmk
    AS $_$
593
SELECT typname::text FROM pg_type WHERE oid = $1
594
$_$;
595
596
597
--
598 8102 aaronmk
-- Name: rename_if_exists(text); Type: FUNCTION; Schema: functions; Owner: -
599
--
600
601
CREATE FUNCTION rename_if_exists(sql text) RETURNS void
602
    LANGUAGE plpgsql STRICT
603
    AS $$
604
BEGIN
605
    EXECUTE sql;
606
EXCEPTION
607
    WHEN undefined_column THEN NULL;
608
END;
609
$$;
610
611
612
--
613
-- Name: FUNCTION rename_if_exists(sql text); Type: COMMENT; Schema: functions; Owner: -
614
--
615
616
COMMENT ON FUNCTION rename_if_exists(sql text) IS 'idempotent';
617
618
619
--
620 8088 aaronmk
-- Name: to_global_col_names(regclass); Type: FUNCTION; Schema: functions; Owner: -
621
--
622
623
CREATE FUNCTION to_global_col_names(table_ regclass) RETURNS void
624
    LANGUAGE plpgsql STRICT
625
    AS $_$
626
DECLARE
627
    row record;
628
BEGIN
629
    FOR row IN SELECT * FROM functions.col_global_names(table_::text::regtype)
630
    LOOP
631
        IF row.global_name != row.name THEN
632
            EXECUTE $$ALTER TABLE $$||table_||$$ RENAME $$
633
                ||quote_ident(row.name)||$$ TO $$||quote_ident(row.global_name);
634
        END IF;
635
    END LOOP;
636
END;
637
$_$;
638
639
640
--
641
-- Name: FUNCTION to_global_col_names(table_ regclass); Type: COMMENT; Schema: functions; Owner: -
642
--
643
644
COMMENT ON FUNCTION to_global_col_names(table_ regclass) IS 'idempotent';
645
646
647
--
648 2595 aaronmk
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: functions; Owner: -
649
--
650
651
CREATE AGGREGATE join_strs(text, text) (
652 4052 aaronmk
    SFUNC = join_strs_transform,
653 4010 aaronmk
    STYPE = text
654 2595 aaronmk
);
655
656
657 2107 aaronmk
--
658 2136 aaronmk
-- PostgreSQL database dump complete
659
--