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: TNRS; Type: SCHEMA; Schema: -; Owner: -
14
--
15

    
16
--CREATE SCHEMA "TNRS";
17

    
18

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

    
23
COMMENT ON SCHEMA "TNRS" IS '
24
IMPORTANT: when changing this schema, you must also make the same changes on vegbiendev:
25
on vegbiendev:
26
# back up existing TNRS schema (in case of an accidental incorrect change):
27
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
28
$ svn up
29
$ svn di
30
# make the changes shown in the diff
31
## to change column types:
32
SELECT util.set_col_types(''"TNRS".taxon_match'', ARRAY[
33
  (''col'', ''new_type'')
34
]::util.col_cast[]); -- runtime: 9 min ("531282 ms")
35
$ rm=1 inputs/.TNRS/schema.sql.run
36
# repeat until `svn di` shows no diff
37
# back up new TNRS schema:
38
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
39
';
40

    
41

    
42
SET search_path = "TNRS", pg_catalog;
43

    
44
--
45
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
46
--
47

    
48
CREATE FUNCTION batch__fill() RETURNS trigger
49
    LANGUAGE plpgsql
50
    AS $$
51
BEGIN
52
	new.id_by_time = new.time_submitted;
53
	new.id = COALESCE(new.id, new.id_by_time);
54
	RETURN new;
55
END;
56
$$;
57

    
58

    
59
--
60
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
61
--
62

    
63
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
64
    LANGUAGE sql STABLE STRICT
65
    AS $_$
66
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
67
$_$;
68

    
69

    
70
--
71
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
72
--
73

    
74
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
75
    LANGUAGE sql STABLE STRICT
76
    AS $_$
77
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
78
$_$;
79

    
80

    
81
--
82
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
83
--
84

    
85
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
86
    LANGUAGE sql IMMUTABLE
87
    AS $_$
88
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
89
"taxonomic_status should be accepted instead of synonym when an accepted name is
90
available (this is not always the case when a name is marked as a synonym)" */
91
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
92
$_$;
93

    
94

    
95
--
96
-- Name: taxon_match__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
97
--
98

    
99
CREATE FUNCTION taxon_match__batch_begin() RETURNS trigger
100
    LANGUAGE plpgsql
101
    AS $$
102
BEGIN
103
	PERFORM util.seq__reset('pg_temp.taxon_match__match_num__seq', 0);
104
	RETURN NULL;
105
END;
106
$$;
107

    
108

    
109
--
110
-- Name: taxon_match__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
111
--
112

    
113
CREATE FUNCTION taxon_match__fill() RETURNS trigger
114
    LANGUAGE plpgsql
115
    AS $$
116
BEGIN
117
	DECLARE
118
		"Specific_epithet_is_plant" boolean :=
119
			(CASE
120
			WHEN   new."*Infraspecific_epithet_matched"	 IS NOT NULL
121
				OR new."*Infraspecific_epithet_2_matched" IS NOT NULL
122
				OR new."*Specific_epithet_score" >= 0.9 -- fuzzy match
123
				THEN true
124
			ELSE NULL -- ambiguous
125
			END);
126
		never_homonym boolean = COALESCE(new."*Author_score" >= 0.6, false);
127
			-- author disambiguates
128
		family_is_homonym boolean = NOT never_homonym
129
			AND "TNRS".family_is_homonym(new."*Family_matched");
130
		genus_is_homonym  boolean = NOT never_homonym
131
			AND "TNRS".genus_is_homonym(new."*Genus_matched");
132
	BEGIN
133
		/* exclude homonyms because these are not valid matches (TNRS provides a
134
		name, but the name is not meaningful because it is not unambiguous) */
135
		new.is_valid_match = new."*Taxonomic_status" != 'Invalid'
136
			AND COALESCE(CASE
137
			WHEN new."*Family_score" = 1 AND NOT family_is_homonym -- exact match
138
				THEN true
139
			ELSE -- consider genus
140
				(CASE
141
				WHEN new."*Genus_score" =  1	   -- exact match
142
					THEN
143
					(CASE
144
					WHEN NOT genus_is_homonym THEN true
145
					ELSE "Specific_epithet_is_plant"
146
					END)
147
				WHEN new."*Genus_score" >= 0.85 -- fuzzy match
148
					THEN "Specific_epithet_is_plant"
149
				ELSE NULL -- ambiguous
150
				END)
151
			END, false);
152
	END;
153
	
154
	DECLARE
155
		matched_taxon_name_with_author text = NULLIF(concat_ws(' '
156
			, NULLIF(NULLIF(new."*Name_matched_accepted_family", 'Unknown'),
157
				new."*Name_matched")
158
			, NULLIF(new."*Name_matched", 'No suitable matches found.')
159
			, new."*Name_matched_author"
160
			), '');
161
		accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
162
			, NULLIF(NULLIF(new."*Accepted_name_family", 'Unknown'),
163
				new."*Accepted_name")
164
			, new."*Accepted_name"
165
			, new."*Accepted_name_author"
166
			), '');
167
	BEGIN
168
		new.scrubbed_unique_taxon_name = COALESCE(
169
			accepted_taxon_name_with_author, matched_taxon_name_with_author);
170
	END;
171
	
172
	RETURN new;
173
END;
174
$$;
175

    
176

    
177
--
178
-- Name: FUNCTION taxon_match__fill(); Type: COMMENT; Schema: TNRS; Owner: -
179
--
180

    
181
COMMENT ON FUNCTION taxon_match__fill() IS '
182
IMPORTANT: when changing this function, you must regenerate the derived cols:
183
UPDATE "TNRS".taxon_match SET "Name_submitted" = "Name_submitted"
184
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
185
VACUUM ANALYZE "TNRS".taxon_match -- to remove previous rows
186
runtime: 1.5 min ("92633 ms")
187
';
188

    
189

    
190
--
191
-- Name: taxon_match__fill_derived(); Type: FUNCTION; Schema: TNRS; Owner: -
192
--
193

    
194
CREATE FUNCTION taxon_match__fill_derived() RETURNS trigger
195
    LANGUAGE plpgsql
196
    AS $$
197
BEGIN
198
	new."__accepted_{genus,specific_epithet}" = (SELECT
199
		regexp_split_to_array("*Accepted_name_species", ' '::text)
200
		FROM (SELECT new.*) new);
201
	
202
	new."[accepted_]genus__@DwC__@vegpath.org" = (SELECT
203
		"__accepted_{genus,specific_epithet}"[1]
204
		FROM (SELECT new.*) new);
205
	
206
	new."[accepted_]specificEpithet__@DwC__@vegpath.org" = (SELECT
207
		"__accepted_{genus,specific_epithet}"[2]
208
		FROM (SELECT new.*) new);
209
	
210
	new.__accepted_infraspecific_label = (SELECT
211
		ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''::text), ' '::text)
212
		FROM (SELECT new.*) new);
213
	
214
	new."__accepted_infraspecific_{rank,epithet}" = (SELECT
215
		regexp_split_to_array(__accepted_infraspecific_label, ' '::text)
216
		FROM (SELECT new.*) new);
217
	
218
	new."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = (SELECT
219
		"__accepted_infraspecific_{rank,epithet}"[1]
220
		FROM (SELECT new.*) new);
221
	
222
	new."[accepted_]infraspecificEpithet__@DwC__@vegpath.org" = (SELECT
223
		"__accepted_infraspecific_{rank,epithet}"[2]
224
		FROM (SELECT new.*) new);
225
	
226
	new."[matched_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT
227
		"*Name_matched" || COALESCE((' '::text || "*Name_matched_author"), ''::text)
228
		FROM (SELECT new.*) new);
229
	
230
	new."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT
231
		"*Accepted_name" || COALESCE((' '::text || "*Accepted_name_author"), ''::text)
232
		FROM (SELECT new.*) new);
233
	
234
	new.matched_has_accepted = (SELECT
235
		"*Accepted_name" IS NOT NULL
236
		FROM (SELECT new.*) new);
237
	
238
	new."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
239
		("*Genus_matched" || ' '::text) || "*Specific_epithet_matched"
240
		FROM (SELECT new.*) new);
241
	
242
	RETURN new;
243
END;
244
$$;
245

    
246

    
247
--
248
-- Name: FUNCTION taxon_match__fill_derived(); Type: COMMENT; Schema: TNRS; Owner: -
249
--
250

    
251
COMMENT ON FUNCTION taxon_match__fill_derived() IS '
252
autogenerated, do not edit
253

    
254
to regenerate:
255
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
256
';
257

    
258

    
259
--
260
-- Name: taxon_match__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
261
--
262

    
263
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
264
    LANGUAGE plpgsql
265
    AS $$
266
BEGIN
267
	IF new.match_num IS NULL THEN
268
		new.match_num = "TNRS".taxon_match__match_num__next();
269
	END IF;
270
	RETURN new;
271
END;
272
$$;
273

    
274

    
275
--
276
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
277
--
278

    
279
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
280
    LANGUAGE sql
281
    AS $$
282
SELECT nextval('pg_temp.taxon_match__match_num__seq');
283
$$;
284

    
285

    
286
--
287
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
288
--
289

    
290
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
291
    LANGUAGE plpgsql
292
    AS $$
293
BEGIN
294
	INSERT INTO "TNRS".taxon_match_input SELECT new.*;
295
	RETURN NULL;
296
END;
297
$$;
298

    
299

    
300
--
301
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
302
--
303

    
304
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
305
    LANGUAGE sql IMMUTABLE
306
    AS $_$
307
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
308
$_$;
309

    
310

    
311
--
312
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
313
--
314

    
315
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
316
    LANGUAGE sql IMMUTABLE
317
    AS $$
318
SELECT ARRAY[
319
]::text[]
320
$$;
321

    
322

    
323
SET default_tablespace = '';
324

    
325
SET default_with_oids = false;
326

    
327
--
328
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
329
--
330

    
331
CREATE TABLE taxon_match (
332
    batch text DEFAULT now() NOT NULL,
333
    match_num integer NOT NULL,
334
    "*Name_number" integer NOT NULL,
335
    "*Name_submitted" text NOT NULL,
336
    "*Overall_score" double precision,
337
    "*Name_matched" text,
338
    "*Name_matched_rank" text,
339
    "*Name_score" double precision,
340
    "*Name_matched_author" text,
341
    "*Name_matched_url" text,
342
    "*Author_matched" text,
343
    "*Author_score" double precision,
344
    "*Family_matched" text,
345
    "*Family_score" double precision,
346
    "*Name_matched_accepted_family" text,
347
    "*Genus_matched" text,
348
    "*Genus_score" double precision,
349
    "*Specific_epithet_matched" text,
350
    "*Specific_epithet_score" double precision,
351
    "*Infraspecific_rank" text,
352
    "*Infraspecific_epithet_matched" text,
353
    "*Infraspecific_epithet_score" double precision,
354
    "*Infraspecific_rank_2" text,
355
    "*Infraspecific_epithet_2_matched" text,
356
    "*Infraspecific_epithet_2_score" double precision,
357
    "*Annotations" text,
358
    "*Unmatched_terms" text,
359
    "*Taxonomic_status" text,
360
    "*Accepted_name" text,
361
    "*Accepted_name_author" text,
362
    "*Accepted_name_rank" text,
363
    "*Accepted_name_url" text,
364
    "*Accepted_name_species" text,
365
    "*Accepted_name_family" text,
366
    "*Selected" text,
367
    "*Source" text,
368
    "*Warnings" text,
369
    "*Accepted_name_lsid" text,
370
    is_valid_match boolean NOT NULL,
371
    scrubbed_unique_taxon_name text,
372
    "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" text,
373
    "[matched_]scientificName[_with_author]__@DwC__@vegpath.org" text,
374
    matched_has_accepted boolean,
375
    "__accepted_{genus,specific_epithet}" text[],
376
    "[accepted_]genus__@DwC__@vegpath.org" text,
377
    "[accepted_]specificEpithet__@DwC__@vegpath.org" text,
378
    __accepted_infraspecific_label text,
379
    "__accepted_infraspecific_{rank,epithet}" text[],
380
    "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" text,
381
    "[accepted_]infraspecificEpithet__@DwC__@vegpath.org" text,
382
    "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" text,
383
    CONSTRAINT "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" CHECK ((NOT ("[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS DISTINCT FROM "__accepted_infraspecific_{rank,epithet}"[1]))),
384
    CONSTRAINT "[accepted_]genus__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]genus__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet}"[1]))),
385
    CONSTRAINT "[accepted_]infraspecificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]infraspecificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_infraspecific_{rank,epithet}"[2]))),
386
    CONSTRAINT "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" IS DISTINCT FROM ("*Accepted_name" || COALESCE((' '::text || "*Accepted_name_author"), ''::text))))),
387
    CONSTRAINT "[accepted_]specificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]specificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet}"[2]))),
388
    CONSTRAINT "[matched_]scientificName[_with_author]__@DwC__@vegpath.org" CHECK ((NOT ("[matched_]scientificName[_with_author]__@DwC__@vegpath.org" IS DISTINCT FROM ("*Name_matched" || COALESCE((' '::text || "*Name_matched_author"), ''::text))))),
389
    CONSTRAINT "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM (("*Genus_matched" || ' '::text) || "*Specific_epithet_matched")))),
390
    CONSTRAINT __accepted_infraspecific_label CHECK ((NOT (__accepted_infraspecific_label IS DISTINCT FROM ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''::text), ' '::text)))),
391
    CONSTRAINT "__accepted_infraspecific_{rank,epithet}" CHECK ((NOT ("__accepted_infraspecific_{rank,epithet}" IS DISTINCT FROM regexp_split_to_array(__accepted_infraspecific_label, ' '::text)))),
392
    CONSTRAINT "__accepted_{genus,specific_epithet}" CHECK ((NOT ("__accepted_{genus,specific_epithet}" IS DISTINCT FROM regexp_split_to_array("*Accepted_name_species", ' '::text)))),
393
    CONSTRAINT matched_has_accepted CHECK ((NOT (matched_has_accepted IS DISTINCT FROM ("*Accepted_name" IS NOT NULL))))
394
);
395

    
396

    
397
--
398
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
399
--
400

    
401
COMMENT ON TABLE taxon_match IS '
402
whenever columns are renamed:
403
SELECT util.derived_cols_sync(''"TNRS".taxon_match'');
404

    
405
to remove columns or add columns at the end:
406
$ rm=1 inputs/.TNRS/data.sql.run
407
$ make schemas/remake
408

    
409
to add columns in the middle:
410
make the changes in inputs/.TNRS/schema.sql
411
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
412
$ make schemas/remake
413

    
414
to populate a new column:
415
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
416
UPDATE "TNRS".taxon_match SET "col" = value;
417
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
418
CLUSTER "TNRS".taxon_match; -- ensure rows are exported in sorted order
419
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
420
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
421

    
422
to add a constraint: runtime: 3 min ("173620 ms")
423
';
424

    
425

    
426
--
427
-- Name: COLUMN taxon_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
428
--
429

    
430
COMMENT ON COLUMN taxon_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
431
derived column; = ("*Genus_matched" || '' ''::text) || "*Specific_epithet_matched"
432

    
433
to modify expr:
434
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$"*Genus_matched" || '' ''::text || "*Specific_epithet_matched"$$)::util.derived_col_def);
435
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
436

    
437
to rename:
438
# rename column
439
# rename CHECK constraint
440
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
441
';
442

    
443

    
444
--
445
-- Name: COLUMN taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
446
--
447

    
448
COMMENT ON COLUMN taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
449
derived column; = "*Name_matched" || COALESCE(('' ''::text || "*Name_matched_author"), ''''::text)
450

    
451
to modify expr:
452
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[matched_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col, $$"*Name_matched" || COALESCE(('' ''::text || "*Name_matched_author"), ''''::text)$$)::util.derived_col_def);
453
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
454

    
455
to rename:
456
# rename column
457
# rename CHECK constraint
458
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
459
';
460

    
461

    
462
--
463
-- Name: COLUMN taxon_match.matched_has_accepted; Type: COMMENT; Schema: TNRS; Owner: -
464
--
465

    
466
COMMENT ON COLUMN taxon_match.matched_has_accepted IS '
467
derived column; = "*Accepted_name" IS NOT NULL
468

    
469
to modify expr:
470
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''matched_has_accepted'')::util.col, $$"*Accepted_name" IS NOT NULL$$)::util.derived_col_def);
471
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
472

    
473
to rename:
474
# rename column
475
# rename CHECK constraint
476
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
477
';
478

    
479

    
480
--
481
-- Name: COLUMN taxon_match."__accepted_{genus,specific_epithet}"; Type: COMMENT; Schema: TNRS; Owner: -
482
--
483

    
484
COMMENT ON COLUMN taxon_match."__accepted_{genus,specific_epithet}" IS '
485
derived column; = regexp_split_to_array("*Accepted_name_species", '' ''::text)
486

    
487
to modify expr:
488
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''__accepted_{genus,specific_epithet}'')::util.col, $$regexp_split_to_array("*Accepted_name_species", '' ''::text)$$)::util.derived_col_def);
489
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
490

    
491
to rename:
492
# rename column
493
# rename CHECK constraint
494
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
495
';
496

    
497

    
498
--
499
-- Name: COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
500
--
501

    
502
COMMENT ON COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org" IS '
503
derived column; = "__accepted_{genus,specific_epithet}"[1]
504

    
505
to modify expr:
506
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]genus__@DwC__@vegpath.org'')::util.col, $$"__accepted_{genus,specific_epithet}"[1]$$)::util.derived_col_def);
507
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
508

    
509
to rename:
510
# rename column
511
# rename CHECK constraint
512
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
513
';
514

    
515

    
516
--
517
-- Name: COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
518
--
519

    
520
COMMENT ON COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org" IS '
521
derived column; = "__accepted_{genus,specific_epithet}"[2]
522

    
523
to modify expr:
524
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]specificEpithet__@DwC__@vegpath.org'')::util.col, $$"__accepted_{genus,specific_epithet}"[2]$$)::util.derived_col_def);
525
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
526

    
527
to rename:
528
# rename column
529
# rename CHECK constraint
530
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
531
';
532

    
533

    
534
--
535
-- Name: COLUMN taxon_match.__accepted_infraspecific_label; Type: COMMENT; Schema: TNRS; Owner: -
536
--
537

    
538
COMMENT ON COLUMN taxon_match.__accepted_infraspecific_label IS '
539
derived column; = ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''''::text), '' ''::text)
540

    
541
to modify expr:
542
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''__accepted_infraspecific_label'')::util.col, $$ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''''::text), '' ''::text)$$)::util.derived_col_def);
543
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
544

    
545
to rename:
546
# rename column
547
# rename CHECK constraint
548
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
549
';
550

    
551

    
552
--
553
-- Name: COLUMN taxon_match."__accepted_infraspecific_{rank,epithet}"; Type: COMMENT; Schema: TNRS; Owner: -
554
--
555

    
556
COMMENT ON COLUMN taxon_match."__accepted_infraspecific_{rank,epithet}" IS '
557
derived column; = regexp_split_to_array(__accepted_infraspecific_label, '' ''::text)
558

    
559
to modify expr:
560
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''__accepted_infraspecific_{rank,epithet}'')::util.col, $$regexp_split_to_array(__accepted_infraspecific_label, '' ''::text)$$)::util.derived_col_def);
561
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
562

    
563
to rename:
564
# rename column
565
# rename CHECK constraint
566
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
567
';
568

    
569

    
570
--
571
-- Name: COLUMN taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
572
--
573

    
574
COMMENT ON COLUMN taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS '
575
derived column; = "__accepted_infraspecific_{rank,epithet}"[1]
576

    
577
to modify expr:
578
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org'')::util.col, $$"__accepted_infraspecific_{rank,epithet}"[1]$$)::util.derived_col_def);
579
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
580

    
581
to rename:
582
# rename column
583
# rename CHECK constraint
584
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
585
';
586

    
587

    
588
--
589
-- Name: COLUMN taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
590
--
591

    
592
COMMENT ON COLUMN taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org" IS '
593
derived column; = "__accepted_infraspecific_{rank,epithet}"[2]
594

    
595
to modify expr:
596
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]infraspecificEpithet__@DwC__@vegpath.org'')::util.col, $$"__accepted_infraspecific_{rank,epithet}"[2]$$)::util.derived_col_def);
597
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
598

    
599
to rename:
600
# rename column
601
# rename CHECK constraint
602
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
603
';
604

    
605

    
606
--
607
-- Name: COLUMN taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
608
--
609

    
610
COMMENT ON COLUMN taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
611
derived column; = "*Accepted_name" || COALESCE(('' ''::text || "*Accepted_name_author"), ''''::text)
612

    
613
to modify expr:
614
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col, $$"*Accepted_name" || COALESCE(('' ''::text || "*Accepted_name_author"), ''''::text)$$)::util.derived_col_def);
615
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
616

    
617
to rename:
618
# rename column
619
# rename CHECK constraint
620
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
621
';
622

    
623

    
624
--
625
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
626
--
627

    
628
CREATE VIEW taxon_best_match AS
629
 SELECT taxon_match.batch,
630
    taxon_match.match_num,
631
    taxon_match."*Name_number",
632
    taxon_match."*Name_submitted",
633
    taxon_match."*Overall_score",
634
    taxon_match."*Name_matched",
635
    taxon_match."*Name_matched_rank",
636
    taxon_match."*Name_score",
637
    taxon_match."*Name_matched_author",
638
    taxon_match."*Name_matched_url",
639
    taxon_match."*Author_matched",
640
    taxon_match."*Author_score",
641
    taxon_match."*Family_matched",
642
    taxon_match."*Family_score",
643
    taxon_match."*Name_matched_accepted_family",
644
    taxon_match."*Genus_matched",
645
    taxon_match."*Genus_score",
646
    taxon_match."*Specific_epithet_matched",
647
    taxon_match."*Specific_epithet_score",
648
    taxon_match."*Infraspecific_rank",
649
    taxon_match."*Infraspecific_epithet_matched",
650
    taxon_match."*Infraspecific_epithet_score",
651
    taxon_match."*Infraspecific_rank_2",
652
    taxon_match."*Infraspecific_epithet_2_matched",
653
    taxon_match."*Infraspecific_epithet_2_score",
654
    taxon_match."*Annotations",
655
    taxon_match."*Unmatched_terms",
656
    taxon_match."*Taxonomic_status",
657
    taxon_match."*Accepted_name",
658
    taxon_match."*Accepted_name_author",
659
    taxon_match."*Accepted_name_rank",
660
    taxon_match."*Accepted_name_url",
661
    taxon_match."*Accepted_name_species",
662
    taxon_match."*Accepted_name_family",
663
    taxon_match."*Selected",
664
    taxon_match."*Source",
665
    taxon_match."*Warnings",
666
    taxon_match."*Accepted_name_lsid",
667
    taxon_match.is_valid_match,
668
    taxon_match.scrubbed_unique_taxon_name,
669
    taxon_match."__accepted_{genus,specific_epithet}",
670
    taxon_match."[accepted_]genus__@DwC__@vegpath.org",
671
    taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org",
672
    taxon_match.__accepted_infraspecific_label,
673
    taxon_match."__accepted_infraspecific_{rank,epithet}",
674
    taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
675
    taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
676
    taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
677
    taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
678
   FROM taxon_match
679
  WHERE (taxon_match."*Selected" = 'true'::text);
680

    
681

    
682
--
683
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
684
--
685

    
686
COMMENT ON VIEW taxon_best_match IS '
687
to modify:
688
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
689
SELECT __
690
$$);
691
';
692

    
693

    
694
--
695
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
696
--
697

    
698
CREATE VIEW "MatchedTaxon" AS
699
 SELECT taxon_best_match.batch,
700
    taxon_best_match.match_num,
701
    taxon_best_match."*Name_number",
702
    taxon_best_match."*Name_submitted",
703
    taxon_best_match."*Overall_score",
704
    taxon_best_match."*Name_matched",
705
    taxon_best_match."*Name_matched_rank",
706
    taxon_best_match."*Name_score",
707
    taxon_best_match."*Name_matched_author",
708
    taxon_best_match."*Name_matched_url",
709
    taxon_best_match."*Author_matched",
710
    taxon_best_match."*Author_score",
711
    taxon_best_match."*Family_matched",
712
    taxon_best_match."*Family_score",
713
    taxon_best_match."*Name_matched_accepted_family",
714
    taxon_best_match."*Genus_matched",
715
    taxon_best_match."*Genus_score",
716
    taxon_best_match."*Specific_epithet_matched",
717
    taxon_best_match."*Specific_epithet_score",
718
    taxon_best_match."*Infraspecific_rank",
719
    taxon_best_match."*Infraspecific_epithet_matched",
720
    taxon_best_match."*Infraspecific_epithet_score",
721
    taxon_best_match."*Infraspecific_rank_2",
722
    taxon_best_match."*Infraspecific_epithet_2_matched",
723
    taxon_best_match."*Infraspecific_epithet_2_score",
724
    taxon_best_match."*Annotations",
725
    taxon_best_match."*Unmatched_terms",
726
    taxon_best_match."*Taxonomic_status",
727
    taxon_best_match."*Accepted_name",
728
    taxon_best_match."*Accepted_name_author",
729
    taxon_best_match."*Accepted_name_rank",
730
    taxon_best_match."*Accepted_name_url",
731
    taxon_best_match."*Accepted_name_species",
732
    taxon_best_match."*Accepted_name_family",
733
    taxon_best_match."*Selected",
734
    taxon_best_match."*Source",
735
    taxon_best_match."*Warnings",
736
    taxon_best_match."*Accepted_name_lsid",
737
    taxon_best_match.is_valid_match,
738
    taxon_best_match.scrubbed_unique_taxon_name,
739
    taxon_best_match."__accepted_{genus,specific_epithet}",
740
    taxon_best_match."[accepted_]genus__@DwC__@vegpath.org",
741
    taxon_best_match."[accepted_]specificEpithet__@DwC__@vegpath.org",
742
    taxon_best_match.__accepted_infraspecific_label,
743
    taxon_best_match."__accepted_infraspecific_{rank,epithet}",
744
    taxon_best_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
745
    taxon_best_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
746
    taxon_best_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
747
    taxon_best_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
748
    map_taxonomic_status(taxon_best_match."*Taxonomic_status", taxon_best_match."*Accepted_name") AS "taxonomicStatus",
749
        CASE
750
            WHEN (taxon_best_match."*Accepted_name_rank" = 'family'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name_family", taxon_best_match."*Unmatched_terms")
751
            WHEN (taxon_best_match."*Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name", taxon_best_match."*Unmatched_terms")
752
            ELSE taxon_best_match."*Accepted_name_species"
753
        END AS accepted_morphospecies_binomial
754
   FROM taxon_best_match;
755

    
756

    
757
--
758
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
759
--
760

    
761
COMMENT ON VIEW "MatchedTaxon" IS '
762
to modify:
763
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
764
SELECT __
765
$$);
766
';
767

    
768

    
769
--
770
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
771
--
772

    
773
CREATE VIEW "ValidMatchedTaxon" AS
774
 SELECT "MatchedTaxon".batch,
775
    "MatchedTaxon".match_num,
776
    "MatchedTaxon"."*Name_number",
777
    "MatchedTaxon"."*Name_submitted",
778
    "MatchedTaxon"."*Overall_score",
779
    "MatchedTaxon"."*Name_matched",
780
    "MatchedTaxon"."*Name_matched_rank",
781
    "MatchedTaxon"."*Name_score",
782
    "MatchedTaxon"."*Name_matched_author",
783
    "MatchedTaxon"."*Name_matched_url",
784
    "MatchedTaxon"."*Author_matched",
785
    "MatchedTaxon"."*Author_score",
786
    "MatchedTaxon"."*Family_matched",
787
    "MatchedTaxon"."*Family_score",
788
    "MatchedTaxon"."*Name_matched_accepted_family",
789
    "MatchedTaxon"."*Genus_matched",
790
    "MatchedTaxon"."*Genus_score",
791
    "MatchedTaxon"."*Specific_epithet_matched",
792
    "MatchedTaxon"."*Specific_epithet_score",
793
    "MatchedTaxon"."*Infraspecific_rank",
794
    "MatchedTaxon"."*Infraspecific_epithet_matched",
795
    "MatchedTaxon"."*Infraspecific_epithet_score",
796
    "MatchedTaxon"."*Infraspecific_rank_2",
797
    "MatchedTaxon"."*Infraspecific_epithet_2_matched",
798
    "MatchedTaxon"."*Infraspecific_epithet_2_score",
799
    "MatchedTaxon"."*Annotations",
800
    "MatchedTaxon"."*Unmatched_terms",
801
    "MatchedTaxon"."*Taxonomic_status",
802
    "MatchedTaxon"."*Accepted_name",
803
    "MatchedTaxon"."*Accepted_name_author",
804
    "MatchedTaxon"."*Accepted_name_rank",
805
    "MatchedTaxon"."*Accepted_name_url",
806
    "MatchedTaxon"."*Accepted_name_species",
807
    "MatchedTaxon"."*Accepted_name_family",
808
    "MatchedTaxon"."*Selected",
809
    "MatchedTaxon"."*Source",
810
    "MatchedTaxon"."*Warnings",
811
    "MatchedTaxon"."*Accepted_name_lsid",
812
    "MatchedTaxon".is_valid_match,
813
    "MatchedTaxon".scrubbed_unique_taxon_name,
814
    "MatchedTaxon"."__accepted_{genus,specific_epithet}",
815
    "MatchedTaxon"."[accepted_]genus__@DwC__@vegpath.org",
816
    "MatchedTaxon"."[accepted_]specificEpithet__@DwC__@vegpath.org",
817
    "MatchedTaxon".__accepted_infraspecific_label,
818
    "MatchedTaxon"."__accepted_infraspecific_{rank,epithet}",
819
    "MatchedTaxon"."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
820
    "MatchedTaxon"."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
821
    "MatchedTaxon"."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
822
    "MatchedTaxon"."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
823
    "MatchedTaxon"."taxonomicStatus",
824
    "MatchedTaxon".accepted_morphospecies_binomial
825
   FROM "MatchedTaxon"
826
  WHERE "MatchedTaxon".is_valid_match;
827

    
828

    
829
--
830
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
831
--
832

    
833
COMMENT ON VIEW "ValidMatchedTaxon" IS '
834
to update, use * as the column list
835
';
836

    
837

    
838
--
839
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
840
--
841

    
842
CREATE TABLE batch (
843
    id text NOT NULL,
844
    id_by_time text,
845
    time_submitted timestamp with time zone DEFAULT now(),
846
    client_version text
847
);
848

    
849

    
850
--
851
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
852
--
853

    
854
CREATE TABLE batch_download_settings (
855
    id text NOT NULL,
856
    "E-mail" text,
857
    "Id" text,
858
    "Job type" text,
859
    "Contains Id" boolean,
860
    "Start time" text,
861
    "Finish time" text,
862
    "TNRS version" text,
863
    "Sources selected" text,
864
    "Match threshold" double precision,
865
    "Classification" text,
866
    "Allow partial matches?" boolean,
867
    "Sort by source" boolean,
868
    "Constrain by higher taxonomy" boolean
869
);
870

    
871

    
872
--
873
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
874
--
875

    
876
COMMENT ON TABLE batch_download_settings IS '
877
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
878
';
879

    
880

    
881
--
882
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
883
--
884

    
885
CREATE TABLE client_version (
886
    id text NOT NULL,
887
    global_rev integer NOT NULL,
888
    "/lib/tnrs.py rev" integer,
889
    "/bin/tnrs_db rev" integer
890
);
891

    
892

    
893
--
894
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
895
--
896

    
897
COMMENT ON TABLE client_version IS '
898
contains svn revisions
899
';
900

    
901

    
902
--
903
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
904
--
905

    
906
COMMENT ON COLUMN client_version.global_rev IS '
907
from `svn info .` > Last Changed Rev
908
';
909

    
910

    
911
--
912
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
913
--
914

    
915
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
916
from `svn info lib/tnrs.py` > Last Changed Rev
917
';
918

    
919

    
920
--
921
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
922
--
923

    
924
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
925
from `svn info bin/tnrs_db` > Last Changed Rev
926
';
927

    
928

    
929
--
930
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
931
--
932

    
933
CREATE VIEW taxon_match_input AS
934
 SELECT taxon_match."*Name_number" AS "Name_number",
935
    taxon_match."*Name_submitted" AS "Name_submitted",
936
    taxon_match."*Overall_score" AS "Overall_score",
937
    taxon_match."*Name_matched" AS "Name_matched",
938
    taxon_match."*Name_matched_rank" AS "Name_matched_rank",
939
    taxon_match."*Name_score" AS "Name_score",
940
    taxon_match."*Name_matched_author" AS "Name_matched_author",
941
    taxon_match."*Name_matched_url" AS "Name_matched_url",
942
    taxon_match."*Author_matched" AS "Author_matched",
943
    taxon_match."*Author_score" AS "Author_score",
944
    taxon_match."*Family_matched" AS "Family_matched",
945
    taxon_match."*Family_score" AS "Family_score",
946
    taxon_match."*Name_matched_accepted_family" AS "Name_matched_accepted_family",
947
    taxon_match."*Genus_matched" AS "Genus_matched",
948
    taxon_match."*Genus_score" AS "Genus_score",
949
    taxon_match."*Specific_epithet_matched" AS "Specific_epithet_matched",
950
    taxon_match."*Specific_epithet_score" AS "Specific_epithet_score",
951
    taxon_match."*Infraspecific_rank" AS "Infraspecific_rank",
952
    taxon_match."*Infraspecific_epithet_matched" AS "Infraspecific_epithet_matched",
953
    taxon_match."*Infraspecific_epithet_score" AS "Infraspecific_epithet_score",
954
    taxon_match."*Infraspecific_rank_2" AS "Infraspecific_rank_2",
955
    taxon_match."*Infraspecific_epithet_2_matched" AS "Infraspecific_epithet_2_matched",
956
    taxon_match."*Infraspecific_epithet_2_score" AS "Infraspecific_epithet_2_score",
957
    taxon_match."*Annotations" AS "Annotations",
958
    taxon_match."*Unmatched_terms" AS "Unmatched_terms",
959
    taxon_match."*Taxonomic_status" AS "Taxonomic_status",
960
    taxon_match."*Accepted_name" AS "Accepted_name",
961
    taxon_match."*Accepted_name_author" AS "Accepted_name_author",
962
    taxon_match."*Accepted_name_rank" AS "Accepted_name_rank",
963
    taxon_match."*Accepted_name_url" AS "Accepted_name_url",
964
    taxon_match."*Accepted_name_species" AS "Accepted_name_species",
965
    taxon_match."*Accepted_name_family" AS "Accepted_name_family",
966
    taxon_match."*Selected" AS "Selected",
967
    taxon_match."*Source" AS "Source",
968
    taxon_match."*Warnings" AS "Warnings",
969
    taxon_match."*Accepted_name_lsid" AS "Accepted_name_lsid"
970
   FROM taxon_match;
971

    
972

    
973
--
974
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
975
--
976

    
977
CREATE TABLE taxon_match_input__copy_to (
978
    "Name_number" integer,
979
    "Name_submitted" text,
980
    "Overall_score" double precision,
981
    "Name_matched" text,
982
    "Name_matched_rank" text,
983
    "Name_score" double precision,
984
    "Name_matched_author" text,
985
    "Name_matched_url" text,
986
    "Author_matched" text,
987
    "Author_score" double precision,
988
    "Family_matched" text,
989
    "Family_score" double precision,
990
    "Name_matched_accepted_family" text,
991
    "Genus_matched" text,
992
    "Genus_score" double precision,
993
    "Specific_epithet_matched" text,
994
    "Specific_epithet_score" double precision,
995
    "Infraspecific_rank" text,
996
    "Infraspecific_epithet_matched" text,
997
    "Infraspecific_epithet_score" double precision,
998
    "Infraspecific_rank_2" text,
999
    "Infraspecific_epithet_2_matched" text,
1000
    "Infraspecific_epithet_2_score" double precision,
1001
    "Annotations" text,
1002
    "Unmatched_terms" text,
1003
    "Taxonomic_status" text,
1004
    "Accepted_name" text,
1005
    "Accepted_name_author" text,
1006
    "Accepted_name_rank" text,
1007
    "Accepted_name_url" text,
1008
    "Accepted_name_species" text,
1009
    "Accepted_name_family" text,
1010
    "Selected" text,
1011
    "Source" text,
1012
    "Warnings" text,
1013
    "Accepted_name_lsid" text
1014
);
1015

    
1016

    
1017
--
1018
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
1019
--
1020

    
1021
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
1022
 SELECT taxon_match."*Name_submitted" AS scrubbed_unique_taxon_name,
1023
    taxon_match."*Name_matched_rank" AS scrubbed_taxon_rank,
1024
    COALESCE(taxon_match."*Name_matched_accepted_family", taxon_match."*Family_matched") AS scrubbed_family,
1025
    taxon_match."*Genus_matched" AS scrubbed_genus,
1026
    taxon_match."*Specific_epithet_matched" AS scrubbed_specific_epithet,
1027
    taxon_match."*Infraspecific_rank" AS scrubbed_infraspecific_rank,
1028
    taxon_match."*Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
1029
    taxon_match."*Name_matched_author" AS scrubbed_author,
1030
    taxon_match."*Name_matched" AS scrubbed_taxon_name_no_author,
1031
    (taxon_match."*Name_matched" || COALESCE((' '::text || taxon_match."*Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
1032
   FROM taxon_match;
1033

    
1034

    
1035
--
1036
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
1037
--
1038

    
1039
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
1040
to modify:
1041
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
1042
SELECT __
1043
$$);
1044

    
1045
scrubbed_family: Name_matched_accepted_family was missing from the TNRS results at one point, so Family_matched is used as a workaround to populate this. the workaround is for *accepted names only*, as no opinion names do not have an Accepted_name_family to prepend to the scrubbed name to parse.
1046
';
1047

    
1048

    
1049
--
1050
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
1051
--
1052

    
1053
CREATE VIEW taxon_scrub AS
1054
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
1055
    "ValidMatchedTaxon".batch,
1056
    "ValidMatchedTaxon".match_num,
1057
    "ValidMatchedTaxon"."*Name_number",
1058
    "ValidMatchedTaxon"."*Name_submitted",
1059
    "ValidMatchedTaxon"."*Overall_score",
1060
    "ValidMatchedTaxon"."*Name_matched",
1061
    "ValidMatchedTaxon"."*Name_matched_rank",
1062
    "ValidMatchedTaxon"."*Name_score",
1063
    "ValidMatchedTaxon"."*Name_matched_author",
1064
    "ValidMatchedTaxon"."*Name_matched_url",
1065
    "ValidMatchedTaxon"."*Author_matched",
1066
    "ValidMatchedTaxon"."*Author_score",
1067
    "ValidMatchedTaxon"."*Family_matched",
1068
    "ValidMatchedTaxon"."*Family_score",
1069
    "ValidMatchedTaxon"."*Name_matched_accepted_family",
1070
    "ValidMatchedTaxon"."*Genus_matched",
1071
    "ValidMatchedTaxon"."*Genus_score",
1072
    "ValidMatchedTaxon"."*Specific_epithet_matched",
1073
    "ValidMatchedTaxon"."*Specific_epithet_score",
1074
    "ValidMatchedTaxon"."*Infraspecific_rank",
1075
    "ValidMatchedTaxon"."*Infraspecific_epithet_matched",
1076
    "ValidMatchedTaxon"."*Infraspecific_epithet_score",
1077
    "ValidMatchedTaxon"."*Infraspecific_rank_2",
1078
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_matched",
1079
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_score",
1080
    "ValidMatchedTaxon"."*Annotations",
1081
    "ValidMatchedTaxon"."*Unmatched_terms",
1082
    "ValidMatchedTaxon"."*Taxonomic_status",
1083
    "ValidMatchedTaxon"."*Accepted_name",
1084
    "ValidMatchedTaxon"."*Accepted_name_author",
1085
    "ValidMatchedTaxon"."*Accepted_name_rank",
1086
    "ValidMatchedTaxon"."*Accepted_name_url",
1087
    "ValidMatchedTaxon"."*Accepted_name_species",
1088
    "ValidMatchedTaxon"."*Accepted_name_family",
1089
    "ValidMatchedTaxon"."*Selected",
1090
    "ValidMatchedTaxon"."*Source",
1091
    "ValidMatchedTaxon"."*Warnings",
1092
    "ValidMatchedTaxon"."*Accepted_name_lsid",
1093
    "ValidMatchedTaxon".is_valid_match,
1094
    "ValidMatchedTaxon"."__accepted_{genus,specific_epithet}",
1095
    "ValidMatchedTaxon"."[accepted_]genus__@DwC__@vegpath.org",
1096
    "ValidMatchedTaxon"."[accepted_]specificEpithet__@DwC__@vegpath.org",
1097
    "ValidMatchedTaxon".__accepted_infraspecific_label,
1098
    "ValidMatchedTaxon"."__accepted_infraspecific_{rank,epithet}",
1099
    "ValidMatchedTaxon"."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
1100
    "ValidMatchedTaxon"."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
1101
    "ValidMatchedTaxon"."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
1102
    "ValidMatchedTaxon"."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
1103
    "ValidMatchedTaxon"."taxonomicStatus",
1104
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
1105
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
1106
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
1107
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
1108
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
1109
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
1110
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
1111
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
1112
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
1113
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
1114
        CASE
1115
            WHEN ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'family'::text) THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, "ValidMatchedTaxon"."*Unmatched_terms")
1116
            WHEN ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, "ValidMatchedTaxon"."*Unmatched_terms")
1117
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
1118
        END AS scrubbed_morphospecies_binomial
1119
   FROM ("ValidMatchedTaxon"
1120
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
1121

    
1122

    
1123
--
1124
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
1125
--
1126

    
1127
COMMENT ON VIEW taxon_scrub IS '
1128
to modify:
1129
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
1130
SELECT __
1131
$$);
1132
';
1133

    
1134

    
1135
--
1136
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1137
--
1138

    
1139
ALTER TABLE ONLY batch_download_settings
1140
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
1141

    
1142

    
1143
--
1144
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1145
--
1146

    
1147
ALTER TABLE ONLY batch
1148
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
1149

    
1150

    
1151
--
1152
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1153
--
1154

    
1155
ALTER TABLE ONLY batch
1156
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
1157

    
1158

    
1159
--
1160
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1161
--
1162

    
1163
ALTER TABLE ONLY client_version
1164
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
1165

    
1166

    
1167
--
1168
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1169
--
1170

    
1171
ALTER TABLE ONLY taxon_match
1172
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
1173

    
1174
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
1175

    
1176

    
1177
--
1178
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
1179
--
1180

    
1181
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
1182

    
1183

    
1184
--
1185
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
1186
--
1187

    
1188
CREATE INDEX taxon_best_match__valid_match ON taxon_match USING btree ("*Name_submitted") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
1189

    
1190

    
1191
--
1192
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
1193
--
1194

    
1195
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
1196

    
1197

    
1198
--
1199
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
1200
--
1201

    
1202
CREATE UNIQUE INDEX taxon_match__one_selected_match ON taxon_match USING btree (batch, "*Name_number") WHERE ("*Selected" = 'true'::text);
1203

    
1204

    
1205
--
1206
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
1207
--
1208

    
1209
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
1210

    
1211

    
1212
--
1213
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
1214
--
1215

    
1216
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
1217

    
1218

    
1219
--
1220
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
1221
--
1222

    
1223
CREATE TRIGGER taxon_match__fill BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill();
1224

    
1225

    
1226
--
1227
-- Name: taxon_match__fill_derived; Type: TRIGGER; Schema: TNRS; Owner: -
1228
--
1229

    
1230
CREATE TRIGGER taxon_match__fill_derived BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill_derived();
1231

    
1232

    
1233
--
1234
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
1235
--
1236

    
1237
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
1238

    
1239

    
1240
--
1241
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
1242
--
1243

    
1244
CREATE TRIGGER taxon_match_input__copy_to__insert BEFORE INSERT ON taxon_match_input__copy_to FOR EACH ROW EXECUTE PROCEDURE taxon_match_input__copy_to__insert();
1245

    
1246

    
1247
--
1248
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1249
--
1250

    
1251
ALTER TABLE ONLY batch
1252
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
1253

    
1254

    
1255
--
1256
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1257
--
1258

    
1259
ALTER TABLE ONLY batch_download_settings
1260
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
1261

    
1262

    
1263
--
1264
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1265
--
1266

    
1267
ALTER TABLE ONLY taxon_match
1268
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
1269

    
1270

    
1271
--
1272
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
1273
--
1274

    
1275
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
1276
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
1277
GRANT ALL ON SCHEMA "TNRS" TO bien;
1278
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
1279

    
1280

    
1281
--
1282
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
1283
--
1284

    
1285
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
1286
REVOKE ALL ON TABLE taxon_match FROM bien;
1287
GRANT ALL ON TABLE taxon_match TO bien;
1288
GRANT SELECT ON TABLE taxon_match TO bien_read;
1289

    
1290

    
1291
--
1292
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
1293
--
1294

    
1295
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
1296
REVOKE ALL ON TABLE taxon_best_match FROM bien;
1297
GRANT ALL ON TABLE taxon_best_match TO bien;
1298
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
1299

    
1300

    
1301
--
1302
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1303
--
1304

    
1305
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
1306
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
1307
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
1308
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
1309

    
1310

    
1311
--
1312
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1313
--
1314

    
1315
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
1316
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
1317
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
1318
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
1319

    
1320

    
1321
--
1322
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
1323
--
1324

    
1325
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
1326
REVOKE ALL ON TABLE taxon_match_input FROM bien;
1327
GRANT ALL ON TABLE taxon_match_input TO bien;
1328
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
1329

    
1330

    
1331
--
1332
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
1333
--
1334

    
1335
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
1336
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
1337
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1338
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1339

    
1340

    
1341
--
1342
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1343
--
1344

    
1345
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1346
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1347
GRANT ALL ON TABLE taxon_scrub TO bien;
1348
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1349

    
1350

    
1351
--
1352
-- PostgreSQL database dump complete
1353
--
1354

    
(7-7/9)