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 regexp_matches($1, '^ *(-?)(\d{2,3})(\d{2})(\d{3}) *([NESW])? *$')
100
)
101
matches (g)
102
$_$;
103

    
104

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

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

    
122

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

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

    
133

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

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

    
146

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

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

    
157

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

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

    
168

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

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

    
179

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

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

    
190

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

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

    
201

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

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

    
226

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

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

    
237

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

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

    
276

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

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

    
287

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

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

    
326

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

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

    
337

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

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

    
348

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

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

    
359

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

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

    
385

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

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

    
396

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

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

    
416

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

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

    
423

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

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

    
434

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

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

    
445

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

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

    
455

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

    
(4-4/25)