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."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
199
		("*Genus_matched" || ' '::text) || "*Specific_epithet_matched"
200
		FROM (SELECT new.*) new);
201
	
202
	new."[matched_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT
203
		"*Name_matched" || COALESCE((' '::text || "*Name_matched_author"), ''::text)
204
		FROM (SELECT new.*) new);
205
	
206
	new.matched_has_accepted = (SELECT
207
		"*Accepted_name" IS NOT NULL
208
		FROM (SELECT new.*) new);
209
	
210
	new."__accepted_{genus,specific_epithet}" = (SELECT
211
		regexp_split_to_array("*Accepted_name_species", ' '::text)
212
		FROM (SELECT new.*) new);
213
	
214
	new."[accepted_]genus__@DwC__@vegpath.org" = (SELECT
215
		"__accepted_{genus,specific_epithet}"[1]
216
		FROM (SELECT new.*) new);
217
	
218
	new."[accepted_]specificEpithet__@DwC__@vegpath.org" = (SELECT
219
		"__accepted_{genus,specific_epithet}"[2]
220
		FROM (SELECT new.*) new);
221
	
222
	new.__accepted_infraspecific_label = (SELECT
223
		ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''::text), ' '::text)
224
		FROM (SELECT new.*) new);
225
	
226
	new."__accepted_infraspecific_{rank,epithet}" = (SELECT
227
		regexp_split_to_array(__accepted_infraspecific_label, ' '::text)
228
		FROM (SELECT new.*) new);
229
	
230
	new."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = (SELECT
231
		"__accepted_infraspecific_{rank,epithet}"[1]
232
		FROM (SELECT new.*) new);
233
	
234
	new."[accepted_]infraspecificEpithet__@DwC__@vegpath.org" = (SELECT
235
		"__accepted_infraspecific_{rank,epithet}"[2]
236
		FROM (SELECT new.*) new);
237
	
238
	new."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT
239
		"*Accepted_name" || COALESCE((' '::text || "*Accepted_name_author"), ''::text)
240
		FROM (SELECT new.*) new);
241
	
242
	new."[scrubbed_]taxonRank__@DwC__@vegpath.org" = (SELECT
243
		CASE
244
    WHEN matched_has_accepted THEN "*Accepted_name_rank"
245
    ELSE "*Name_matched_rank"
246
END
247
		FROM (SELECT new.*) new);
248
	
249
	new."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
250
		CASE
251
    WHEN matched_has_accepted THEN "*Accepted_name_family"
252
    ELSE "*Name_matched_accepted_family"
253
END
254
		FROM (SELECT new.*) new);
255
	
256
	new."[scrubbed_]genus__@DwC__@vegpath.org" = (SELECT
257
		CASE
258
    WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
259
    ELSE "*Genus_matched"
260
END
261
		FROM (SELECT new.*) new);
262
	
263
	new."[scrubbed_]specificEpithet__@DwC__@vegpath.org" = (SELECT
264
		CASE
265
    WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
266
    ELSE "*Specific_epithet_matched"
267
END
268
		FROM (SELECT new.*) new);
269
	
270
	new."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
271
		CASE
272
    WHEN matched_has_accepted THEN "*Accepted_name_species"
273
    ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
274
END
275
		FROM (SELECT new.*) new);
276
	
277
	new."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = (SELECT
278
		CASE
279
    WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
280
    ELSE "*Infraspecific_rank"
281
END
282
		FROM (SELECT new.*) new);
283
	
284
	new."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" = (SELECT
285
		CASE
286
    WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
287
    ELSE "*Infraspecific_epithet_matched"
288
END
289
		FROM (SELECT new.*) new);
290
	
291
	new."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
292
		CASE
293
    WHEN matched_has_accepted THEN "*Accepted_name"
294
    ELSE "*Name_matched"
295
END
296
		FROM (SELECT new.*) new);
297
	
298
	new."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
299
		CASE
300
    WHEN matched_has_accepted THEN "*Accepted_name_author"
301
    ELSE "*Name_matched_author"
302
END
303
		FROM (SELECT new.*) new);
304
	
305
	new."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT
306
		CASE
307
    WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
308
    ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
309
END
310
		FROM (SELECT new.*) new);
311
	
312
	RETURN new;
313
END;
314
$$;
315

    
316

    
317
--
318
-- Name: FUNCTION taxon_match__fill_derived(); Type: COMMENT; Schema: TNRS; Owner: -
319
--
320

    
321
COMMENT ON FUNCTION taxon_match__fill_derived() IS '
322
autogenerated, do not edit
323

    
324
to regenerate:
325
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
326
';
327

    
328

    
329
--
330
-- Name: taxon_match__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
331
--
332

    
333
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
334
    LANGUAGE plpgsql
335
    AS $$
336
BEGIN
337
	IF new.match_num IS NULL THEN
338
		new.match_num = "TNRS".taxon_match__match_num__next();
339
	END IF;
340
	RETURN new;
341
END;
342
$$;
343

    
344

    
345
--
346
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
347
--
348

    
349
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
350
    LANGUAGE sql
351
    AS $$
352
SELECT nextval('pg_temp.taxon_match__match_num__seq');
353
$$;
354

    
355

    
356
--
357
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
358
--
359

    
360
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
361
    LANGUAGE plpgsql
362
    AS $$
363
BEGIN
364
	INSERT INTO "TNRS".taxon_match_input SELECT new.*;
365
	RETURN NULL;
366
END;
367
$$;
368

    
369

    
370
--
371
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
372
--
373

    
374
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
375
    LANGUAGE sql IMMUTABLE
376
    AS $_$
377
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
378
$_$;
379

    
380

    
381
--
382
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
383
--
384

    
385
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
386
    LANGUAGE sql IMMUTABLE
387
    AS $$
388
SELECT ARRAY[
389
]::text[]
390
$$;
391

    
392

    
393
SET default_tablespace = '';
394

    
395
SET default_with_oids = false;
396

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

    
401
CREATE TABLE taxon_match (
402
    batch text DEFAULT now() NOT NULL,
403
    match_num integer NOT NULL,
404
    "*Name_number" integer NOT NULL,
405
    "*Name_submitted" text NOT NULL,
406
    "*Overall_score" double precision,
407
    "*Name_matched" text,
408
    "*Name_matched_rank" text,
409
    "*Name_score" double precision,
410
    "*Name_matched_author" text,
411
    "*Name_matched_url" text,
412
    "*Author_matched" text,
413
    "*Author_score" double precision,
414
    "*Family_matched" text,
415
    "*Family_score" double precision,
416
    "*Name_matched_accepted_family" text,
417
    "*Genus_matched" text,
418
    "*Genus_score" double precision,
419
    "*Specific_epithet_matched" text,
420
    "*Specific_epithet_score" double precision,
421
    "*Infraspecific_rank" text,
422
    "*Infraspecific_epithet_matched" text,
423
    "*Infraspecific_epithet_score" double precision,
424
    "*Infraspecific_rank_2" text,
425
    "*Infraspecific_epithet_2_matched" text,
426
    "*Infraspecific_epithet_2_score" double precision,
427
    "*Annotations" text,
428
    "*Unmatched_terms" text,
429
    "*Taxonomic_status" text,
430
    "*Accepted_name" text,
431
    "*Accepted_name_author" text,
432
    "*Accepted_name_rank" text,
433
    "*Accepted_name_url" text,
434
    "*Accepted_name_species" text,
435
    "*Accepted_name_family" text,
436
    "*Selected" text,
437
    "*Source" text,
438
    "*Warnings" text,
439
    "*Accepted_name_lsid" text,
440
    is_valid_match boolean NOT NULL,
441
    scrubbed_unique_taxon_name text,
442
    "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" text,
443
    "[matched_]scientificName[_with_author]__@DwC__@vegpath.org" text,
444
    matched_has_accepted boolean,
445
    "__accepted_{genus,specific_epithet}" text[],
446
    "[accepted_]genus__@DwC__@vegpath.org" text,
447
    "[accepted_]specificEpithet__@DwC__@vegpath.org" text,
448
    __accepted_infraspecific_label text,
449
    "__accepted_infraspecific_{rank,epithet}" text[],
450
    "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" text,
451
    "[accepted_]infraspecificEpithet__@DwC__@vegpath.org" text,
452
    "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" text,
453
    "[scrubbed_]taxonRank__@DwC__@vegpath.org" text,
454
    "[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" text,
455
    "[scrubbed_]genus__@DwC__@vegpath.org" text,
456
    "[scrubbed_]specificEpithet__@DwC__@vegpath.org" text,
457
    "[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" text,
458
    "[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" text,
459
    "[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" text,
460
    "[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" text,
461
    "[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" text,
462
    "[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" text,
463
    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]))),
464
    CONSTRAINT "[accepted_]genus__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]genus__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet}"[1]))),
465
    CONSTRAINT "[accepted_]infraspecificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]infraspecificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_infraspecific_{rank,epithet}"[2]))),
466
    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))))),
467
    CONSTRAINT "[accepted_]specificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]specificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet}"[2]))),
468
    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))))),
469
    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")))),
470
    CONSTRAINT "[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS DISTINCT FROM
471
CASE
472
    WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
473
    ELSE "*Infraspecific_rank"
474
END))),
475
    CONSTRAINT "[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
476
CASE
477
    WHEN matched_has_accepted THEN "*Accepted_name_author"
478
    ELSE "*Name_matched_author"
479
END))),
480
    CONSTRAINT "[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
481
CASE
482
    WHEN matched_has_accepted THEN "*Accepted_name_family"
483
    ELSE "*Name_matched_accepted_family"
484
END))),
485
    CONSTRAINT "[scrubbed_]genus__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]genus__@DwC__@vegpath.org" IS DISTINCT FROM
486
CASE
487
    WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
488
    ELSE "*Genus_matched"
489
END))),
490
    CONSTRAINT "[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM
491
CASE
492
    WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
493
    ELSE "*Infraspecific_epithet_matched"
494
END))),
495
    CONSTRAINT "[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
496
CASE
497
    WHEN matched_has_accepted THEN "*Accepted_name"
498
    ELSE "*Name_matched"
499
END))),
500
    CONSTRAINT "[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" IS DISTINCT FROM
501
CASE
502
    WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
503
    ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
504
END))),
505
    CONSTRAINT "[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
506
CASE
507
    WHEN matched_has_accepted THEN "*Accepted_name_species"
508
    ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
509
END))),
510
    CONSTRAINT "[scrubbed_]specificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]specificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM
511
CASE
512
    WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
513
    ELSE "*Specific_epithet_matched"
514
END))),
515
    CONSTRAINT "[scrubbed_]taxonRank__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]taxonRank__@DwC__@vegpath.org" IS DISTINCT FROM
516
CASE
517
    WHEN matched_has_accepted THEN "*Accepted_name_rank"
518
    ELSE "*Name_matched_rank"
519
END))),
520
    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)))),
521
    CONSTRAINT "__accepted_infraspecific_{rank,epithet}" CHECK ((NOT ("__accepted_infraspecific_{rank,epithet}" IS DISTINCT FROM regexp_split_to_array(__accepted_infraspecific_label, ' '::text)))),
522
    CONSTRAINT "__accepted_{genus,specific_epithet}" CHECK ((NOT ("__accepted_{genus,specific_epithet}" IS DISTINCT FROM regexp_split_to_array("*Accepted_name_species", ' '::text)))),
523
    CONSTRAINT matched_has_accepted CHECK ((NOT (matched_has_accepted IS DISTINCT FROM ("*Accepted_name" IS NOT NULL))))
524
);
525

    
526

    
527
--
528
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
529
--
530

    
531
COMMENT ON TABLE taxon_match IS '
532
whenever columns are renamed:
533
SELECT util.derived_cols_sync(''"TNRS".taxon_match'');
534

    
535
to remove columns or add columns at the end:
536
$ rm=1 inputs/.TNRS/data.sql.run
537
$ make schemas/remake
538

    
539
to add columns in the middle:
540
make the changes in inputs/.TNRS/schema.sql
541
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
542
$ make schemas/remake
543

    
544
to populate a new column:
545
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
546
UPDATE "TNRS".taxon_match SET "col" = value;
547
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
548
CLUSTER "TNRS".taxon_match; -- ensure rows are exported in sorted order
549
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
550
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
551

    
552
to add a constraint: runtime: 3 min ("173620 ms")
553
';
554

    
555

    
556
--
557
-- Name: COLUMN taxon_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
558
--
559

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

    
563
to modify expr:
564
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);
565
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
566

    
567
to rename:
568
# rename column
569
# rename CHECK constraint
570
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
571
';
572

    
573

    
574
--
575
-- Name: COLUMN taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
576
--
577

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

    
581
to modify expr:
582
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);
583
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
584

    
585
to rename:
586
# rename column
587
# rename CHECK constraint
588
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
589
';
590

    
591

    
592
--
593
-- Name: COLUMN taxon_match.matched_has_accepted; Type: COMMENT; Schema: TNRS; Owner: -
594
--
595

    
596
COMMENT ON COLUMN taxon_match.matched_has_accepted IS '
597
derived column; = "*Accepted_name" IS NOT NULL
598

    
599
to modify expr:
600
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''matched_has_accepted'')::util.col, $$"*Accepted_name" IS NOT NULL$$)::util.derived_col_def);
601
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
602

    
603
to rename:
604
# rename column
605
# rename CHECK constraint
606
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
607
';
608

    
609

    
610
--
611
-- Name: COLUMN taxon_match."__accepted_{genus,specific_epithet}"; Type: COMMENT; Schema: TNRS; Owner: -
612
--
613

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

    
617
to modify expr:
618
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);
619
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
620

    
621
to rename:
622
# rename column
623
# rename CHECK constraint
624
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
625
';
626

    
627

    
628
--
629
-- Name: COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
630
--
631

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

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

    
639
to rename:
640
# rename column
641
# rename CHECK constraint
642
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
643
';
644

    
645

    
646
--
647
-- Name: COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
648
--
649

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

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

    
657
to rename:
658
# rename column
659
# rename CHECK constraint
660
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
661
';
662

    
663

    
664
--
665
-- Name: COLUMN taxon_match.__accepted_infraspecific_label; Type: COMMENT; Schema: TNRS; Owner: -
666
--
667

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

    
671
to modify expr:
672
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);
673
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
674

    
675
to rename:
676
# rename column
677
# rename CHECK constraint
678
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
679
';
680

    
681

    
682
--
683
-- Name: COLUMN taxon_match."__accepted_infraspecific_{rank,epithet}"; Type: COMMENT; Schema: TNRS; Owner: -
684
--
685

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

    
689
to modify expr:
690
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);
691
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
692

    
693
to rename:
694
# rename column
695
# rename CHECK constraint
696
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
697
';
698

    
699

    
700
--
701
-- Name: COLUMN taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
702
--
703

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

    
707
to modify expr:
708
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);
709
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
710

    
711
to rename:
712
# rename column
713
# rename CHECK constraint
714
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
715
';
716

    
717

    
718
--
719
-- Name: COLUMN taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
720
--
721

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

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

    
729
to rename:
730
# rename column
731
# rename CHECK constraint
732
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
733
';
734

    
735

    
736
--
737
-- Name: COLUMN taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
738
--
739

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

    
743
to modify expr:
744
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);
745
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
746

    
747
to rename:
748
# rename column
749
# rename CHECK constraint
750
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
751
';
752

    
753

    
754
--
755
-- Name: COLUMN taxon_match."[scrubbed_]taxonRank__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
756
--
757

    
758
COMMENT ON COLUMN taxon_match."[scrubbed_]taxonRank__@DwC__@vegpath.org" IS '
759
derived column; = CASE
760
    WHEN matched_has_accepted THEN "*Accepted_name_rank"
761
    ELSE "*Name_matched_rank"
762
END
763

    
764
to modify expr:
765
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]taxonRank__@DwC__@vegpath.org'')::util.col, $$CASE
766
    WHEN matched_has_accepted THEN "*Accepted_name_rank"
767
    ELSE "*Name_matched_rank"
768
END$$)::util.derived_col_def);
769
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
770

    
771
to rename:
772
# rename column
773
# rename CHECK constraint
774
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
775
';
776

    
777

    
778
--
779
-- Name: COLUMN taxon_match."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
780
--
781

    
782
COMMENT ON COLUMN taxon_match."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" IS '
783
derived column; = CASE
784
    WHEN matched_has_accepted THEN "*Accepted_name_family"
785
    ELSE "*Name_matched_accepted_family"
786
END
787

    
788
to modify expr:
789
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE
790
    WHEN matched_has_accepted THEN "*Accepted_name_family"
791
    ELSE "*Name_matched_accepted_family"
792
END$$)::util.derived_col_def);
793
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
794

    
795
to rename:
796
# rename column
797
# rename CHECK constraint
798
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
799
';
800

    
801

    
802
--
803
-- Name: COLUMN taxon_match."[scrubbed_]genus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
804
--
805

    
806
COMMENT ON COLUMN taxon_match."[scrubbed_]genus__@DwC__@vegpath.org" IS '
807
derived column; = CASE
808
    WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
809
    ELSE "*Genus_matched"
810
END
811

    
812
to modify expr:
813
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]genus__@DwC__@vegpath.org'')::util.col, $$CASE
814
    WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
815
    ELSE "*Genus_matched"
816
END$$)::util.derived_col_def);
817
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
818

    
819
to rename:
820
# rename column
821
# rename CHECK constraint
822
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
823
';
824

    
825

    
826
--
827
-- Name: COLUMN taxon_match."[scrubbed_]specificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
828
--
829

    
830
COMMENT ON COLUMN taxon_match."[scrubbed_]specificEpithet__@DwC__@vegpath.org" IS '
831
derived column; = CASE
832
    WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
833
    ELSE "*Specific_epithet_matched"
834
END
835

    
836
to modify expr:
837
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]specificEpithet__@DwC__@vegpath.org'')::util.col, $$CASE
838
    WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
839
    ELSE "*Specific_epithet_matched"
840
END$$)::util.derived_col_def);
841
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
842

    
843
to rename:
844
# rename column
845
# rename CHECK constraint
846
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
847
';
848

    
849

    
850
--
851
-- Name: COLUMN taxon_match."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
852
--
853

    
854
COMMENT ON COLUMN taxon_match."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
855
derived column; = CASE
856
    WHEN matched_has_accepted THEN "*Accepted_name_species"
857
    ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
858
END
859

    
860
to modify expr:
861
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE
862
    WHEN matched_has_accepted THEN "*Accepted_name_species"
863
    ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
864
END$$)::util.derived_col_def);
865
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
866

    
867
to rename:
868
# rename column
869
# rename CHECK constraint
870
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
871
';
872

    
873

    
874
--
875
-- Name: COLUMN taxon_match."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
876
--
877

    
878
COMMENT ON COLUMN taxon_match."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS '
879
derived column; = CASE
880
    WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
881
    ELSE "*Infraspecific_rank"
882
END
883

    
884
to modify expr:
885
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org'')::util.col, $$CASE
886
    WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
887
    ELSE "*Infraspecific_rank"
888
END$$)::util.derived_col_def);
889
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
890

    
891
to rename:
892
# rename column
893
# rename CHECK constraint
894
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
895
';
896

    
897

    
898
--
899
-- Name: COLUMN taxon_match."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
900
--
901

    
902
COMMENT ON COLUMN taxon_match."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" IS '
903
derived column; = CASE
904
    WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
905
    ELSE "*Infraspecific_epithet_matched"
906
END
907

    
908
to modify expr:
909
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org'')::util.col, $$CASE
910
    WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
911
    ELSE "*Infraspecific_epithet_matched"
912
END$$)::util.derived_col_def);
913
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
914

    
915
to rename:
916
# rename column
917
# rename CHECK constraint
918
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
919
';
920

    
921

    
922
--
923
-- Name: COLUMN taxon_match."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
924
--
925

    
926
COMMENT ON COLUMN taxon_match."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
927
derived column; = CASE
928
    WHEN matched_has_accepted THEN "*Accepted_name"
929
    ELSE "*Name_matched"
930
END
931

    
932
to modify expr:
933
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE
934
    WHEN matched_has_accepted THEN "*Accepted_name"
935
    ELSE "*Name_matched"
936
END$$)::util.derived_col_def);
937
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
938

    
939
to rename:
940
# rename column
941
# rename CHECK constraint
942
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
943
';
944

    
945

    
946
--
947
-- Name: COLUMN taxon_match."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
948
--
949

    
950
COMMENT ON COLUMN taxon_match."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" IS '
951
derived column; = CASE
952
    WHEN matched_has_accepted THEN "*Accepted_name_author"
953
    ELSE "*Name_matched_author"
954
END
955

    
956
to modify expr:
957
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE
958
    WHEN matched_has_accepted THEN "*Accepted_name_author"
959
    ELSE "*Name_matched_author"
960
END$$)::util.derived_col_def);
961
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
962

    
963
to rename:
964
# rename column
965
# rename CHECK constraint
966
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
967
';
968

    
969

    
970
--
971
-- Name: COLUMN taxon_match."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
972
--
973

    
974
COMMENT ON COLUMN taxon_match."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
975
derived column; = CASE
976
    WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
977
    ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
978
END
979

    
980
to modify expr:
981
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col, $$CASE
982
    WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
983
    ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
984
END$$)::util.derived_col_def);
985
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
986

    
987
to rename:
988
# rename column
989
# rename CHECK constraint
990
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
991
';
992

    
993

    
994
--
995
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
996
--
997

    
998
CREATE VIEW taxon_best_match AS
999
 SELECT taxon_match.batch,
1000
    taxon_match.match_num,
1001
    taxon_match."*Name_number",
1002
    taxon_match."*Name_submitted",
1003
    taxon_match."*Overall_score",
1004
    taxon_match."*Name_matched",
1005
    taxon_match."*Name_matched_rank",
1006
    taxon_match."*Name_score",
1007
    taxon_match."*Name_matched_author",
1008
    taxon_match."*Name_matched_url",
1009
    taxon_match."*Author_matched",
1010
    taxon_match."*Author_score",
1011
    taxon_match."*Family_matched",
1012
    taxon_match."*Family_score",
1013
    taxon_match."*Name_matched_accepted_family",
1014
    taxon_match."*Genus_matched",
1015
    taxon_match."*Genus_score",
1016
    taxon_match."*Specific_epithet_matched",
1017
    taxon_match."*Specific_epithet_score",
1018
    taxon_match."*Infraspecific_rank",
1019
    taxon_match."*Infraspecific_epithet_matched",
1020
    taxon_match."*Infraspecific_epithet_score",
1021
    taxon_match."*Infraspecific_rank_2",
1022
    taxon_match."*Infraspecific_epithet_2_matched",
1023
    taxon_match."*Infraspecific_epithet_2_score",
1024
    taxon_match."*Annotations",
1025
    taxon_match."*Unmatched_terms",
1026
    taxon_match."*Taxonomic_status",
1027
    taxon_match."*Accepted_name",
1028
    taxon_match."*Accepted_name_author",
1029
    taxon_match."*Accepted_name_rank",
1030
    taxon_match."*Accepted_name_url",
1031
    taxon_match."*Accepted_name_species",
1032
    taxon_match."*Accepted_name_family",
1033
    taxon_match."*Selected",
1034
    taxon_match."*Source",
1035
    taxon_match."*Warnings",
1036
    taxon_match."*Accepted_name_lsid",
1037
    taxon_match.is_valid_match,
1038
    taxon_match.scrubbed_unique_taxon_name,
1039
    taxon_match."__accepted_{genus,specific_epithet}",
1040
    taxon_match."[accepted_]genus__@DwC__@vegpath.org",
1041
    taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org",
1042
    taxon_match.__accepted_infraspecific_label,
1043
    taxon_match."__accepted_infraspecific_{rank,epithet}",
1044
    taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
1045
    taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
1046
    taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
1047
    taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
1048
   FROM taxon_match
1049
  WHERE (taxon_match."*Selected" = 'true'::text);
1050

    
1051

    
1052
--
1053
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
1054
--
1055

    
1056
COMMENT ON VIEW taxon_best_match IS '
1057
to modify:
1058
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
1059
SELECT __
1060
$$);
1061
';
1062

    
1063

    
1064
--
1065
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
1066
--
1067

    
1068
CREATE VIEW "MatchedTaxon" AS
1069
 SELECT taxon_best_match.batch,
1070
    taxon_best_match.match_num,
1071
    taxon_best_match."*Name_number",
1072
    taxon_best_match."*Name_submitted",
1073
    taxon_best_match."*Overall_score",
1074
    taxon_best_match."*Name_matched",
1075
    taxon_best_match."*Name_matched_rank",
1076
    taxon_best_match."*Name_score",
1077
    taxon_best_match."*Name_matched_author",
1078
    taxon_best_match."*Name_matched_url",
1079
    taxon_best_match."*Author_matched",
1080
    taxon_best_match."*Author_score",
1081
    taxon_best_match."*Family_matched",
1082
    taxon_best_match."*Family_score",
1083
    taxon_best_match."*Name_matched_accepted_family",
1084
    taxon_best_match."*Genus_matched",
1085
    taxon_best_match."*Genus_score",
1086
    taxon_best_match."*Specific_epithet_matched",
1087
    taxon_best_match."*Specific_epithet_score",
1088
    taxon_best_match."*Infraspecific_rank",
1089
    taxon_best_match."*Infraspecific_epithet_matched",
1090
    taxon_best_match."*Infraspecific_epithet_score",
1091
    taxon_best_match."*Infraspecific_rank_2",
1092
    taxon_best_match."*Infraspecific_epithet_2_matched",
1093
    taxon_best_match."*Infraspecific_epithet_2_score",
1094
    taxon_best_match."*Annotations",
1095
    taxon_best_match."*Unmatched_terms",
1096
    taxon_best_match."*Taxonomic_status",
1097
    taxon_best_match."*Accepted_name",
1098
    taxon_best_match."*Accepted_name_author",
1099
    taxon_best_match."*Accepted_name_rank",
1100
    taxon_best_match."*Accepted_name_url",
1101
    taxon_best_match."*Accepted_name_species",
1102
    taxon_best_match."*Accepted_name_family",
1103
    taxon_best_match."*Selected",
1104
    taxon_best_match."*Source",
1105
    taxon_best_match."*Warnings",
1106
    taxon_best_match."*Accepted_name_lsid",
1107
    taxon_best_match.is_valid_match,
1108
    taxon_best_match.scrubbed_unique_taxon_name,
1109
    taxon_best_match."__accepted_{genus,specific_epithet}",
1110
    taxon_best_match."[accepted_]genus__@DwC__@vegpath.org",
1111
    taxon_best_match."[accepted_]specificEpithet__@DwC__@vegpath.org",
1112
    taxon_best_match.__accepted_infraspecific_label,
1113
    taxon_best_match."__accepted_infraspecific_{rank,epithet}",
1114
    taxon_best_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
1115
    taxon_best_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
1116
    taxon_best_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
1117
    taxon_best_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
1118
    map_taxonomic_status(taxon_best_match."*Taxonomic_status", taxon_best_match."*Accepted_name") AS "taxonomicStatus",
1119
        CASE
1120
            WHEN (taxon_best_match."*Accepted_name_rank" = 'family'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name_family", taxon_best_match."*Unmatched_terms")
1121
            WHEN (taxon_best_match."*Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name", taxon_best_match."*Unmatched_terms")
1122
            ELSE taxon_best_match."*Accepted_name_species"
1123
        END AS accepted_morphospecies_binomial
1124
   FROM taxon_best_match;
1125

    
1126

    
1127
--
1128
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
1129
--
1130

    
1131
COMMENT ON VIEW "MatchedTaxon" IS '
1132
to modify:
1133
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
1134
SELECT __
1135
$$);
1136
';
1137

    
1138

    
1139
--
1140
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
1141
--
1142

    
1143
CREATE VIEW "ValidMatchedTaxon" AS
1144
 SELECT "MatchedTaxon".batch,
1145
    "MatchedTaxon".match_num,
1146
    "MatchedTaxon"."*Name_number",
1147
    "MatchedTaxon"."*Name_submitted",
1148
    "MatchedTaxon"."*Overall_score",
1149
    "MatchedTaxon"."*Name_matched",
1150
    "MatchedTaxon"."*Name_matched_rank",
1151
    "MatchedTaxon"."*Name_score",
1152
    "MatchedTaxon"."*Name_matched_author",
1153
    "MatchedTaxon"."*Name_matched_url",
1154
    "MatchedTaxon"."*Author_matched",
1155
    "MatchedTaxon"."*Author_score",
1156
    "MatchedTaxon"."*Family_matched",
1157
    "MatchedTaxon"."*Family_score",
1158
    "MatchedTaxon"."*Name_matched_accepted_family",
1159
    "MatchedTaxon"."*Genus_matched",
1160
    "MatchedTaxon"."*Genus_score",
1161
    "MatchedTaxon"."*Specific_epithet_matched",
1162
    "MatchedTaxon"."*Specific_epithet_score",
1163
    "MatchedTaxon"."*Infraspecific_rank",
1164
    "MatchedTaxon"."*Infraspecific_epithet_matched",
1165
    "MatchedTaxon"."*Infraspecific_epithet_score",
1166
    "MatchedTaxon"."*Infraspecific_rank_2",
1167
    "MatchedTaxon"."*Infraspecific_epithet_2_matched",
1168
    "MatchedTaxon"."*Infraspecific_epithet_2_score",
1169
    "MatchedTaxon"."*Annotations",
1170
    "MatchedTaxon"."*Unmatched_terms",
1171
    "MatchedTaxon"."*Taxonomic_status",
1172
    "MatchedTaxon"."*Accepted_name",
1173
    "MatchedTaxon"."*Accepted_name_author",
1174
    "MatchedTaxon"."*Accepted_name_rank",
1175
    "MatchedTaxon"."*Accepted_name_url",
1176
    "MatchedTaxon"."*Accepted_name_species",
1177
    "MatchedTaxon"."*Accepted_name_family",
1178
    "MatchedTaxon"."*Selected",
1179
    "MatchedTaxon"."*Source",
1180
    "MatchedTaxon"."*Warnings",
1181
    "MatchedTaxon"."*Accepted_name_lsid",
1182
    "MatchedTaxon".is_valid_match,
1183
    "MatchedTaxon".scrubbed_unique_taxon_name,
1184
    "MatchedTaxon"."__accepted_{genus,specific_epithet}",
1185
    "MatchedTaxon"."[accepted_]genus__@DwC__@vegpath.org",
1186
    "MatchedTaxon"."[accepted_]specificEpithet__@DwC__@vegpath.org",
1187
    "MatchedTaxon".__accepted_infraspecific_label,
1188
    "MatchedTaxon"."__accepted_infraspecific_{rank,epithet}",
1189
    "MatchedTaxon"."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
1190
    "MatchedTaxon"."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
1191
    "MatchedTaxon"."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
1192
    "MatchedTaxon"."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
1193
    "MatchedTaxon"."taxonomicStatus",
1194
    "MatchedTaxon".accepted_morphospecies_binomial
1195
   FROM "MatchedTaxon"
1196
  WHERE "MatchedTaxon".is_valid_match;
1197

    
1198

    
1199
--
1200
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
1201
--
1202

    
1203
COMMENT ON VIEW "ValidMatchedTaxon" IS '
1204
to update, use * as the column list
1205
';
1206

    
1207

    
1208
--
1209
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
1210
--
1211

    
1212
CREATE TABLE batch (
1213
    id text NOT NULL,
1214
    id_by_time text,
1215
    time_submitted timestamp with time zone DEFAULT now(),
1216
    client_version text
1217
);
1218

    
1219

    
1220
--
1221
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
1222
--
1223

    
1224
CREATE TABLE batch_download_settings (
1225
    id text NOT NULL,
1226
    "E-mail" text,
1227
    "Id" text,
1228
    "Job type" text,
1229
    "Contains Id" boolean,
1230
    "Start time" text,
1231
    "Finish time" text,
1232
    "TNRS version" text,
1233
    "Sources selected" text,
1234
    "Match threshold" double precision,
1235
    "Classification" text,
1236
    "Allow partial matches?" boolean,
1237
    "Sort by source" boolean,
1238
    "Constrain by higher taxonomy" boolean
1239
);
1240

    
1241

    
1242
--
1243
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
1244
--
1245

    
1246
COMMENT ON TABLE batch_download_settings IS '
1247
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
1248
';
1249

    
1250

    
1251
--
1252
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
1253
--
1254

    
1255
CREATE TABLE client_version (
1256
    id text NOT NULL,
1257
    global_rev integer NOT NULL,
1258
    "/lib/tnrs.py rev" integer,
1259
    "/bin/tnrs_db rev" integer
1260
);
1261

    
1262

    
1263
--
1264
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
1265
--
1266

    
1267
COMMENT ON TABLE client_version IS '
1268
contains svn revisions
1269
';
1270

    
1271

    
1272
--
1273
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
1274
--
1275

    
1276
COMMENT ON COLUMN client_version.global_rev IS '
1277
from `svn info .` > Last Changed Rev
1278
';
1279

    
1280

    
1281
--
1282
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
1283
--
1284

    
1285
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
1286
from `svn info lib/tnrs.py` > Last Changed Rev
1287
';
1288

    
1289

    
1290
--
1291
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
1292
--
1293

    
1294
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
1295
from `svn info bin/tnrs_db` > Last Changed Rev
1296
';
1297

    
1298

    
1299
--
1300
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
1301
--
1302

    
1303
CREATE VIEW taxon_match_input AS
1304
 SELECT taxon_match."*Name_number" AS "Name_number",
1305
    taxon_match."*Name_submitted" AS "Name_submitted",
1306
    taxon_match."*Overall_score" AS "Overall_score",
1307
    taxon_match."*Name_matched" AS "Name_matched",
1308
    taxon_match."*Name_matched_rank" AS "Name_matched_rank",
1309
    taxon_match."*Name_score" AS "Name_score",
1310
    taxon_match."*Name_matched_author" AS "Name_matched_author",
1311
    taxon_match."*Name_matched_url" AS "Name_matched_url",
1312
    taxon_match."*Author_matched" AS "Author_matched",
1313
    taxon_match."*Author_score" AS "Author_score",
1314
    taxon_match."*Family_matched" AS "Family_matched",
1315
    taxon_match."*Family_score" AS "Family_score",
1316
    taxon_match."*Name_matched_accepted_family" AS "Name_matched_accepted_family",
1317
    taxon_match."*Genus_matched" AS "Genus_matched",
1318
    taxon_match."*Genus_score" AS "Genus_score",
1319
    taxon_match."*Specific_epithet_matched" AS "Specific_epithet_matched",
1320
    taxon_match."*Specific_epithet_score" AS "Specific_epithet_score",
1321
    taxon_match."*Infraspecific_rank" AS "Infraspecific_rank",
1322
    taxon_match."*Infraspecific_epithet_matched" AS "Infraspecific_epithet_matched",
1323
    taxon_match."*Infraspecific_epithet_score" AS "Infraspecific_epithet_score",
1324
    taxon_match."*Infraspecific_rank_2" AS "Infraspecific_rank_2",
1325
    taxon_match."*Infraspecific_epithet_2_matched" AS "Infraspecific_epithet_2_matched",
1326
    taxon_match."*Infraspecific_epithet_2_score" AS "Infraspecific_epithet_2_score",
1327
    taxon_match."*Annotations" AS "Annotations",
1328
    taxon_match."*Unmatched_terms" AS "Unmatched_terms",
1329
    taxon_match."*Taxonomic_status" AS "Taxonomic_status",
1330
    taxon_match."*Accepted_name" AS "Accepted_name",
1331
    taxon_match."*Accepted_name_author" AS "Accepted_name_author",
1332
    taxon_match."*Accepted_name_rank" AS "Accepted_name_rank",
1333
    taxon_match."*Accepted_name_url" AS "Accepted_name_url",
1334
    taxon_match."*Accepted_name_species" AS "Accepted_name_species",
1335
    taxon_match."*Accepted_name_family" AS "Accepted_name_family",
1336
    taxon_match."*Selected" AS "Selected",
1337
    taxon_match."*Source" AS "Source",
1338
    taxon_match."*Warnings" AS "Warnings",
1339
    taxon_match."*Accepted_name_lsid" AS "Accepted_name_lsid"
1340
   FROM taxon_match;
1341

    
1342

    
1343
--
1344
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
1345
--
1346

    
1347
CREATE TABLE taxon_match_input__copy_to (
1348
    "Name_number" integer,
1349
    "Name_submitted" text,
1350
    "Overall_score" double precision,
1351
    "Name_matched" text,
1352
    "Name_matched_rank" text,
1353
    "Name_score" double precision,
1354
    "Name_matched_author" text,
1355
    "Name_matched_url" text,
1356
    "Author_matched" text,
1357
    "Author_score" double precision,
1358
    "Family_matched" text,
1359
    "Family_score" double precision,
1360
    "Name_matched_accepted_family" text,
1361
    "Genus_matched" text,
1362
    "Genus_score" double precision,
1363
    "Specific_epithet_matched" text,
1364
    "Specific_epithet_score" double precision,
1365
    "Infraspecific_rank" text,
1366
    "Infraspecific_epithet_matched" text,
1367
    "Infraspecific_epithet_score" double precision,
1368
    "Infraspecific_rank_2" text,
1369
    "Infraspecific_epithet_2_matched" text,
1370
    "Infraspecific_epithet_2_score" double precision,
1371
    "Annotations" text,
1372
    "Unmatched_terms" text,
1373
    "Taxonomic_status" text,
1374
    "Accepted_name" text,
1375
    "Accepted_name_author" text,
1376
    "Accepted_name_rank" text,
1377
    "Accepted_name_url" text,
1378
    "Accepted_name_species" text,
1379
    "Accepted_name_family" text,
1380
    "Selected" text,
1381
    "Source" text,
1382
    "Warnings" text,
1383
    "Accepted_name_lsid" text
1384
);
1385

    
1386

    
1387
--
1388
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
1389
--
1390

    
1391
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
1392
 SELECT taxon_match."*Name_submitted" AS scrubbed_unique_taxon_name,
1393
    taxon_match."*Name_matched_rank" AS scrubbed_taxon_rank,
1394
    COALESCE(taxon_match."*Name_matched_accepted_family", taxon_match."*Family_matched") AS scrubbed_family,
1395
    taxon_match."*Genus_matched" AS scrubbed_genus,
1396
    taxon_match."*Specific_epithet_matched" AS scrubbed_specific_epithet,
1397
    taxon_match."*Infraspecific_rank" AS scrubbed_infraspecific_rank,
1398
    taxon_match."*Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
1399
    taxon_match."*Name_matched_author" AS scrubbed_author,
1400
    taxon_match."*Name_matched" AS scrubbed_taxon_name_no_author,
1401
    (taxon_match."*Name_matched" || COALESCE((' '::text || taxon_match."*Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
1402
   FROM taxon_match;
1403

    
1404

    
1405
--
1406
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
1407
--
1408

    
1409
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
1410
to modify:
1411
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
1412
SELECT __
1413
$$);
1414

    
1415
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.
1416
';
1417

    
1418

    
1419
--
1420
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
1421
--
1422

    
1423
CREATE VIEW taxon_scrub AS
1424
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
1425
    "ValidMatchedTaxon".batch,
1426
    "ValidMatchedTaxon".match_num,
1427
    "ValidMatchedTaxon"."*Name_number",
1428
    "ValidMatchedTaxon"."*Name_submitted",
1429
    "ValidMatchedTaxon"."*Overall_score",
1430
    "ValidMatchedTaxon"."*Name_matched",
1431
    "ValidMatchedTaxon"."*Name_matched_rank",
1432
    "ValidMatchedTaxon"."*Name_score",
1433
    "ValidMatchedTaxon"."*Name_matched_author",
1434
    "ValidMatchedTaxon"."*Name_matched_url",
1435
    "ValidMatchedTaxon"."*Author_matched",
1436
    "ValidMatchedTaxon"."*Author_score",
1437
    "ValidMatchedTaxon"."*Family_matched",
1438
    "ValidMatchedTaxon"."*Family_score",
1439
    "ValidMatchedTaxon"."*Name_matched_accepted_family",
1440
    "ValidMatchedTaxon"."*Genus_matched",
1441
    "ValidMatchedTaxon"."*Genus_score",
1442
    "ValidMatchedTaxon"."*Specific_epithet_matched",
1443
    "ValidMatchedTaxon"."*Specific_epithet_score",
1444
    "ValidMatchedTaxon"."*Infraspecific_rank",
1445
    "ValidMatchedTaxon"."*Infraspecific_epithet_matched",
1446
    "ValidMatchedTaxon"."*Infraspecific_epithet_score",
1447
    "ValidMatchedTaxon"."*Infraspecific_rank_2",
1448
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_matched",
1449
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_score",
1450
    "ValidMatchedTaxon"."*Annotations",
1451
    "ValidMatchedTaxon"."*Unmatched_terms",
1452
    "ValidMatchedTaxon"."*Taxonomic_status",
1453
    "ValidMatchedTaxon"."*Accepted_name",
1454
    "ValidMatchedTaxon"."*Accepted_name_author",
1455
    "ValidMatchedTaxon"."*Accepted_name_rank",
1456
    "ValidMatchedTaxon"."*Accepted_name_url",
1457
    "ValidMatchedTaxon"."*Accepted_name_species",
1458
    "ValidMatchedTaxon"."*Accepted_name_family",
1459
    "ValidMatchedTaxon"."*Selected",
1460
    "ValidMatchedTaxon"."*Source",
1461
    "ValidMatchedTaxon"."*Warnings",
1462
    "ValidMatchedTaxon"."*Accepted_name_lsid",
1463
    "ValidMatchedTaxon".is_valid_match,
1464
    "ValidMatchedTaxon"."__accepted_{genus,specific_epithet}",
1465
    "ValidMatchedTaxon"."[accepted_]genus__@DwC__@vegpath.org",
1466
    "ValidMatchedTaxon"."[accepted_]specificEpithet__@DwC__@vegpath.org",
1467
    "ValidMatchedTaxon".__accepted_infraspecific_label,
1468
    "ValidMatchedTaxon"."__accepted_infraspecific_{rank,epithet}",
1469
    "ValidMatchedTaxon"."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
1470
    "ValidMatchedTaxon"."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
1471
    "ValidMatchedTaxon"."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
1472
    "ValidMatchedTaxon"."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
1473
    "ValidMatchedTaxon"."taxonomicStatus",
1474
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
1475
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
1476
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
1477
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
1478
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
1479
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
1480
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
1481
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
1482
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
1483
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
1484
        CASE
1485
            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")
1486
            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")
1487
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
1488
        END AS scrubbed_morphospecies_binomial
1489
   FROM ("ValidMatchedTaxon"
1490
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
1491

    
1492

    
1493
--
1494
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
1495
--
1496

    
1497
COMMENT ON VIEW taxon_scrub IS '
1498
to modify:
1499
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
1500
SELECT __
1501
$$);
1502
';
1503

    
1504

    
1505
--
1506
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1507
--
1508

    
1509
ALTER TABLE ONLY batch_download_settings
1510
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
1511

    
1512

    
1513
--
1514
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1515
--
1516

    
1517
ALTER TABLE ONLY batch
1518
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
1519

    
1520

    
1521
--
1522
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1523
--
1524

    
1525
ALTER TABLE ONLY batch
1526
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
1527

    
1528

    
1529
--
1530
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1531
--
1532

    
1533
ALTER TABLE ONLY client_version
1534
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
1535

    
1536

    
1537
--
1538
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
1539
--
1540

    
1541
ALTER TABLE ONLY taxon_match
1542
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
1543

    
1544
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
1545

    
1546

    
1547
--
1548
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
1549
--
1550

    
1551
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
1552

    
1553

    
1554
--
1555
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
1556
--
1557

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

    
1560

    
1561
--
1562
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
1563
--
1564

    
1565
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
1566

    
1567

    
1568
--
1569
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
1570
--
1571

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

    
1574

    
1575
--
1576
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
1577
--
1578

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

    
1581

    
1582
--
1583
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
1584
--
1585

    
1586
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
1587

    
1588

    
1589
--
1590
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
1591
--
1592

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

    
1595

    
1596
--
1597
-- Name: taxon_match__fill_derived; Type: TRIGGER; Schema: TNRS; Owner: -
1598
--
1599

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

    
1602

    
1603
--
1604
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
1605
--
1606

    
1607
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
1608

    
1609

    
1610
--
1611
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
1612
--
1613

    
1614
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();
1615

    
1616

    
1617
--
1618
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1619
--
1620

    
1621
ALTER TABLE ONLY batch
1622
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
1623

    
1624

    
1625
--
1626
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1627
--
1628

    
1629
ALTER TABLE ONLY batch_download_settings
1630
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
1631

    
1632

    
1633
--
1634
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1635
--
1636

    
1637
ALTER TABLE ONLY taxon_match
1638
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
1639

    
1640

    
1641
--
1642
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
1643
--
1644

    
1645
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
1646
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
1647
GRANT ALL ON SCHEMA "TNRS" TO bien;
1648
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
1649

    
1650

    
1651
--
1652
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
1653
--
1654

    
1655
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
1656
REVOKE ALL ON TABLE taxon_match FROM bien;
1657
GRANT ALL ON TABLE taxon_match TO bien;
1658
GRANT SELECT ON TABLE taxon_match TO bien_read;
1659

    
1660

    
1661
--
1662
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
1663
--
1664

    
1665
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
1666
REVOKE ALL ON TABLE taxon_best_match FROM bien;
1667
GRANT ALL ON TABLE taxon_best_match TO bien;
1668
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
1669

    
1670

    
1671
--
1672
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1673
--
1674

    
1675
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
1676
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
1677
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
1678
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
1679

    
1680

    
1681
--
1682
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1683
--
1684

    
1685
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
1686
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
1687
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
1688
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
1689

    
1690

    
1691
--
1692
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
1693
--
1694

    
1695
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
1696
REVOKE ALL ON TABLE taxon_match_input FROM bien;
1697
GRANT ALL ON TABLE taxon_match_input TO bien;
1698
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
1699

    
1700

    
1701
--
1702
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
1703
--
1704

    
1705
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
1706
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
1707
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1708
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1709

    
1710

    
1711
--
1712
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1713
--
1714

    
1715
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1716
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1717
GRANT ALL ON TABLE taxon_scrub TO bien;
1718
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1719

    
1720

    
1721
--
1722
-- PostgreSQL database dump complete
1723
--
1724

    
(7-7/9)