Project

General

Profile

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

    
5
SET statement_timeout = 0;
6
SET client_encoding = 'UTF8';
7
SET standard_conforming_strings = on;
8
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
--
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
SET search_path = functions, pg_catalog;
26

    
27
--
28
-- 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
-- Name: datatype; Type: TYPE; Schema: functions; Owner: -
41
--
42

    
43
CREATE TYPE datatype AS ENUM (
44
    'str',
45
    'float'
46
);
47

    
48

    
49
--
50
-- Name: _alt(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
51
--
52

    
53
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
    LANGUAGE sql IMMUTABLE
55
    AS $_$
56
SELECT coalesce($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)
57
$_$;
58

    
59

    
60
--
61
-- Name: _and(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: functions; Owner: -
62
--
63

    
64
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
    LANGUAGE sql IMMUTABLE
66
    AS $_$
67
SELECT bool_and(value)
68
FROM
69
(VALUES
70
      ($1)
71
    , ($2)
72
    , ($3)
73
    , ($4)
74
    , ($5)
75
)
76
AS v (value)
77
$_$;
78

    
79

    
80
--
81
-- Name: FUNCTION _and("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: functions; Owner: -
82
--
83

    
84
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

    
86

    
87
--
88
-- Name: _dms_to_dd(text); Type: FUNCTION; Schema: functions; Owner: -
89
--
90

    
91
CREATE FUNCTION _dms_to_dd(value text DEFAULT NULL::text) RETURNS double precision
92
    LANGUAGE sql IMMUTABLE STRICT
93
    AS $_$
94
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)
95
FROM 
96
(
97
    SELECT regexp_matches($1, '^ *(-?)(\d{1,3}(?:\.\d*)?)(?:(?:deg|[°º])(?: *([\d.]+)(?:min|[''’]))?(?: *([\d.]+)(?:sec|["”]))?)? *([NESW])? *$')
98
    UNION ALL
99
    SELECT ARRAY[g[1], g[2], g[3]||'.'||g[4], NULL, g[5]]
100
    FROM regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$') matches (g) -- [D]DDMMmmm, where MMmmm = MM.mmm
101
)
102
matches (g)
103
$_$;
104

    
105

    
106
--
107
-- Name: _dms_to_dd(double precision, double precision, double precision, compass_dir); Type: FUNCTION; Schema: functions; Owner: -
108
--
109

    
110
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
111
    LANGUAGE sql IMMUTABLE
112
    AS $_$
113
SELECT sum(value)*COALESCE(functions._map('N=>1,E=>1,S=>-1,W=>-1', $4::text)::integer, 1)
114
FROM
115
(VALUES
116
      ($1)
117
    , ($2/60)
118
    , ($3/60/60)
119
)
120
AS v (value)
121
$_$;
122

    
123

    
124
--
125
-- Name: _eq(anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
126
--
127

    
128
CREATE FUNCTION _eq("left" anyelement DEFAULT NULL::unknown, "right" anyelement DEFAULT NULL::unknown) RETURNS boolean
129
    LANGUAGE sql IMMUTABLE
130
    AS $_$
131
SELECT $1 = $2
132
$_$;
133

    
134

    
135
--
136
-- Name: _fix_date(date, date); Type: FUNCTION; Schema: functions; Owner: -
137
--
138

    
139
CREATE FUNCTION _fix_date(value date DEFAULT NULL::date, threshold date DEFAULT NULL::date) RETURNS date
140
    LANGUAGE sql IMMUTABLE
141
    AS $_$
142
-- Fix dates after threshold date
143
-- This fixes e.g. 2-digit years before 1970 misinterpreted as 20xx
144
SELECT (CASE WHEN $1 > COALESCE($2, now()) THEN ($1 - '100 years'::interval)::date ELSE $1 END)
145
$_$;
146

    
147

    
148
--
149
-- Name: _if(boolean, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
150
--
151

    
152
CREATE FUNCTION _if(cond boolean DEFAULT NULL::boolean, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
153
    LANGUAGE sql IMMUTABLE
154
    AS $_$
155
SELECT (CASE WHEN $1 THEN $2 ELSE $3 END)
156
$_$;
157

    
158

    
159
--
160
-- Name: _if(text, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
161
--
162

    
163
CREATE FUNCTION _if(cond text DEFAULT NULL::text, "then" anyelement DEFAULT NULL::unknown, "else" anyelement DEFAULT NULL::unknown) RETURNS anyelement
164
    LANGUAGE sql IMMUTABLE
165
    AS $_$
166
SELECT functions._if($1 != '', $2, $3)
167
$_$;
168

    
169

    
170
--
171
-- Name: _join(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
172
--
173

    
174
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
175
    LANGUAGE sql IMMUTABLE
176
    AS $_$
177
SELECT nullif(array_to_string(ARRAY[$1, $2, $3, $4, $5, $6, $7, $8, $9, $10], '; '), '')
178
$_$;
179

    
180

    
181
--
182
-- Name: _join_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
183
--
184

    
185
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
186
    LANGUAGE sql IMMUTABLE
187
    AS $_$
188
SELECT nullif(array_to_string(ARRAY[$1, $2, $3, $4, $5, $6, $7, $8, $9, $10], ' '), '')
189
$_$;
190

    
191

    
192
--
193
-- Name: _label(anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
194
--
195

    
196
CREATE FUNCTION _label(label anyelement, value anyelement) RETURNS anyelement
197
    LANGUAGE sql IMMUTABLE
198
    AS $_$
199
SELECT coalesce($1 || ': ', '') || $2
200
$_$;
201

    
202

    
203
--
204
-- Name: _map(hstore, text); Type: FUNCTION; Schema: functions; Owner: -
205
--
206

    
207
CREATE FUNCTION _map(map hstore, value text) RETURNS text
208
    LANGUAGE plpgsql IMMUTABLE
209
    AS $$
210
DECLARE
211
    match text := map -> value;
212
BEGIN
213
    IF match IS NULL AND NOT map ? value THEN -- no match rather than NULL match
214
        match := map -> '*'; -- use default entry
215
        IF match IS NULL AND NOT map ? '*' THEN match := '!'; -- no default
216
        END IF;
217
    END IF;
218
    
219
    -- Interpret result
220
    IF match = '!' THEN RAISE 'Value not in map: %', value USING ERRCODE = 'data_exception';
221
    ELSIF match = '*' THEN RETURN value;
222
    ELSE RETURN match;
223
    END IF;
224
END;
225
$$;
226

    
227

    
228
--
229
-- Name: _max(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
230
--
231

    
232
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
233
    LANGUAGE sql IMMUTABLE
234
    AS $_$
235
SELECT GREATEST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
236
$_$;
237

    
238

    
239
--
240
-- Name: _merge(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
241
--
242

    
243
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
244
    LANGUAGE sql IMMUTABLE
245
    AS $_$
246
SELECT functions.join_strs(value, '; ')
247
FROM
248
(
249
    SELECT *
250
    FROM
251
    (
252
        SELECT
253
        DISTINCT ON (value)
254
        *
255
        FROM
256
        (VALUES
257
              (1, $1)
258
            , (2, $2)
259
            , (3, $3)
260
            , (4, $4)
261
            , (5, $5)
262
            , (6, $6)
263
            , (7, $7)
264
            , (8, $8)
265
            , (9, $9)
266
            , (10, $10)
267
        )
268
        AS v (sort_order, value)
269
        WHERE value IS NOT NULL
270
    )
271
    AS v
272
    ORDER BY sort_order
273
)
274
AS v
275
$_$;
276

    
277

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

    
282
CREATE FUNCTION _merge_prefix(prefix text DEFAULT NULL::text, value text DEFAULT NULL::text) RETURNS text
283
    LANGUAGE sql IMMUTABLE
284
    AS $_$
285
SELECT _join_words((CASE WHEN $2 ~ ('^'||$1||E'\\y') THEN NULL ELSE $1 END), $2)
286
$_$;
287

    
288

    
289
--
290
-- Name: _merge_words(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
291
--
292

    
293
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
294
    LANGUAGE sql IMMUTABLE
295
    AS $_$
296
SELECT functions.join_strs(value, ' ')
297
FROM
298
(
299
    SELECT *
300
    FROM
301
    (
302
        SELECT
303
        DISTINCT ON (value)
304
        *
305
        FROM
306
        (VALUES
307
              (1, $1)
308
            , (2, $2)
309
            , (3, $3)
310
            , (4, $4)
311
            , (5, $5)
312
            , (6, $6)
313
            , (7, $7)
314
            , (8, $8)
315
            , (9, $9)
316
            , (10, $10)
317
        )
318
        AS v (sort_order, value)
319
        WHERE value IS NOT NULL
320
    )
321
    AS v
322
    ORDER BY sort_order
323
)
324
AS v
325
$_$;
326

    
327

    
328
--
329
-- Name: _min(anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement, anyelement); Type: FUNCTION; Schema: functions; Owner: -
330
--
331

    
332
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
333
    LANGUAGE sql IMMUTABLE
334
    AS $_$
335
SELECT LEAST($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
336
$_$;
337

    
338

    
339
--
340
-- Name: _not(boolean); Type: FUNCTION; Schema: functions; Owner: -
341
--
342

    
343
CREATE FUNCTION _not(value boolean) RETURNS boolean
344
    LANGUAGE sql IMMUTABLE STRICT
345
    AS $_$
346
SELECT NOT $1
347
$_$;
348

    
349

    
350
--
351
-- Name: _now(); Type: FUNCTION; Schema: functions; Owner: -
352
--
353

    
354
CREATE FUNCTION _now() RETURNS timestamp with time zone
355
    LANGUAGE sql STABLE
356
    AS $$
357
SELECT now()
358
$$;
359

    
360

    
361
--
362
-- Name: _nullIf(anyelement, text, datatype); Type: FUNCTION; Schema: functions; Owner: -
363
--
364

    
365
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type datatype DEFAULT 'str'::datatype) RETURNS anyelement
366
    LANGUAGE plpgsql IMMUTABLE
367
    AS $$
368
DECLARE
369
    type functions.datatype NOT NULL := type; -- add NOT NULL
370
BEGIN
371
    IF type = 'str' THEN RETURN nullif(value::text, "null");
372
    -- Invalid value is ignored, but invalid null value generates error
373
    ELSIF type = 'float' THEN
374
        DECLARE
375
            -- Outside the try block so that invalid null value generates error
376
            "null" double precision := "null"::double precision;
377
        BEGIN
378
            RETURN nullif(value::double precision, "null");
379
        EXCEPTION
380
            WHEN data_exception THEN RETURN value; -- ignore invalid value
381
        END;
382
    END IF;
383
END;
384
$$;
385

    
386

    
387
--
388
-- Name: _nullIf(anyelement, text, text); Type: FUNCTION; Schema: functions; Owner: -
389
--
390

    
391
CREATE FUNCTION "_nullIf"(value anyelement, "null" text, type text) RETURNS anyelement
392
    LANGUAGE sql IMMUTABLE
393
    AS $_$
394
SELECT functions."_nullIf"($1, $2, $3::functions.datatype)
395
$_$;
396

    
397

    
398
--
399
-- Name: _or(boolean, boolean, boolean, boolean, boolean); Type: FUNCTION; Schema: functions; Owner: -
400
--
401

    
402
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
403
    LANGUAGE sql IMMUTABLE
404
    AS $_$
405
SELECT bool_or(value)
406
FROM
407
(VALUES
408
      ($1)
409
    , ($2)
410
    , ($3)
411
    , ($4)
412
    , ($5)
413
)
414
AS v (value)
415
$_$;
416

    
417

    
418
--
419
-- Name: FUNCTION _or("0" boolean, "1" boolean, "2" boolean, "3" boolean, "4" boolean); Type: COMMENT; Schema: functions; Owner: -
420
--
421

    
422
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.';
423

    
424

    
425
--
426
-- Name: _split(text, text); Type: FUNCTION; Schema: functions; Owner: -
427
--
428

    
429
CREATE FUNCTION _split(value text DEFAULT NULL::text, separator text DEFAULT '; '::text) RETURNS SETOF text
430
    LANGUAGE sql IMMUTABLE STRICT
431
    AS $_$
432
SELECT regexp_split_to_table($1, $2)
433
$_$;
434

    
435

    
436
--
437
-- Name: join_strs_transform(text, text, text); Type: FUNCTION; Schema: functions; Owner: -
438
--
439

    
440
CREATE FUNCTION join_strs_transform(state text, value text, delim text) RETURNS text
441
    LANGUAGE sql IMMUTABLE STRICT
442
    AS $_$
443
SELECT $1 || $3 || $2
444
$_$;
445

    
446

    
447
--
448
-- Name: join_strs(text, text); Type: AGGREGATE; Schema: functions; Owner: -
449
--
450

    
451
CREATE AGGREGATE join_strs(text, text) (
452
    SFUNC = join_strs_transform,
453
    STYPE = text
454
);
455

    
456

    
457
--
458
-- PostgreSQL database dump complete
459
--
460

    
(4-4/25)