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__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
192
--
193

    
194
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
195
    LANGUAGE plpgsql
196
    AS $$
197
BEGIN
198
	IF new.match_num IS NULL THEN
199
		new.match_num = "TNRS".taxon_match__match_num__next();
200
	END IF;
201
	RETURN new;
202
END;
203
$$;
204

    
205

    
206
--
207
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
208
--
209

    
210
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
211
    LANGUAGE sql
212
    AS $$
213
SELECT nextval('pg_temp.taxon_match__match_num__seq');
214
$$;
215

    
216

    
217
--
218
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
219
--
220

    
221
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
222
    LANGUAGE plpgsql
223
    AS $$
224
BEGIN
225
	INSERT INTO "TNRS".taxon_match_input SELECT new.*;
226
	RETURN NULL;
227
END;
228
$$;
229

    
230

    
231
--
232
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
233
--
234

    
235
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
236
    LANGUAGE sql IMMUTABLE
237
    AS $_$
238
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
239
$_$;
240

    
241

    
242
--
243
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
244
--
245

    
246
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
247
    LANGUAGE sql IMMUTABLE
248
    AS $$
249
SELECT ARRAY[
250
]::text[]
251
$$;
252

    
253

    
254
SET default_tablespace = '';
255

    
256
SET default_with_oids = false;
257

    
258
--
259
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
260
--
261

    
262
CREATE TABLE taxon_match (
263
    batch text DEFAULT now() NOT NULL,
264
    match_num integer NOT NULL,
265
    "Name_number" integer NOT NULL,
266
    "Name_submitted" text NOT NULL,
267
    "Overall_score" double precision,
268
    "Name_matched" text,
269
    "Name_matched_rank" text,
270
    "Name_score" double precision,
271
    "Name_matched_author" text,
272
    "Name_matched_url" text,
273
    "Author_matched" text,
274
    "Author_score" double precision,
275
    "Family_matched" text,
276
    "Family_score" double precision,
277
    "Name_matched_accepted_family" text,
278
    "Genus_matched" text,
279
    "Genus_score" double precision,
280
    "Specific_epithet_matched" text,
281
    "Specific_epithet_score" double precision,
282
    "Infraspecific_rank" text,
283
    "Infraspecific_epithet_matched" text,
284
    "Infraspecific_epithet_score" double precision,
285
    "Infraspecific_rank_2" text,
286
    "Infraspecific_epithet_2_matched" text,
287
    "Infraspecific_epithet_2_score" double precision,
288
    "Annotations" text,
289
    "Unmatched_terms" text,
290
    "Taxonomic_status" text,
291
    "Accepted_name" text,
292
    "Accepted_name_author" text,
293
    "Accepted_name_rank" text,
294
    "Accepted_name_url" text,
295
    "Accepted_name_species" text,
296
    "Accepted_name_family" text,
297
    "Selected" text,
298
    "Source" text,
299
    "Warnings" text,
300
    "Accepted_name_lsid" text,
301
    is_valid_match boolean NOT NULL,
302
    scrubbed_unique_taxon_name text
303
);
304

    
305

    
306
--
307
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
308
--
309

    
310
COMMENT ON TABLE taxon_match IS '
311
to remove columns or add columns at the end:
312
$ rm=1 inputs/.TNRS/data.sql.run
313
$ make schemas/remake
314

    
315
to add columns in the middle:
316
make the changes in inputs/.TNRS/schema.sql
317
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
318
$ make schemas/remake
319

    
320
to populate a new column:
321
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
322
UPDATE "TNRS".taxon_match SET "col" = value;
323
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
324
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
325
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
326

    
327
to add a constraint: runtime: 3 min ("173620 ms")
328
';
329

    
330

    
331
--
332
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
333
--
334

    
335
CREATE VIEW taxon_best_match AS
336
 SELECT taxon_match.batch,
337
    taxon_match.match_num,
338
    taxon_match."Name_number",
339
    taxon_match."Name_submitted",
340
    taxon_match."Overall_score",
341
    taxon_match."Name_matched",
342
    taxon_match."Name_matched_rank",
343
    taxon_match."Name_score",
344
    taxon_match."Name_matched_author",
345
    taxon_match."Name_matched_url",
346
    taxon_match."Author_matched",
347
    taxon_match."Author_score",
348
    taxon_match."Family_matched",
349
    taxon_match."Family_score",
350
    taxon_match."Name_matched_accepted_family",
351
    taxon_match."Genus_matched",
352
    taxon_match."Genus_score",
353
    taxon_match."Specific_epithet_matched",
354
    taxon_match."Specific_epithet_score",
355
    taxon_match."Infraspecific_rank",
356
    taxon_match."Infraspecific_epithet_matched",
357
    taxon_match."Infraspecific_epithet_score",
358
    taxon_match."Infraspecific_rank_2",
359
    taxon_match."Infraspecific_epithet_2_matched",
360
    taxon_match."Infraspecific_epithet_2_score",
361
    taxon_match."Annotations",
362
    taxon_match."Unmatched_terms",
363
    taxon_match."Taxonomic_status",
364
    taxon_match."Accepted_name",
365
    taxon_match."Accepted_name_author",
366
    taxon_match."Accepted_name_rank",
367
    taxon_match."Accepted_name_url",
368
    taxon_match."Accepted_name_species",
369
    taxon_match."Accepted_name_family",
370
    taxon_match."Selected",
371
    taxon_match."Source",
372
    taxon_match."Warnings",
373
    taxon_match."Accepted_name_lsid",
374
    taxon_match.is_valid_match,
375
    taxon_match.scrubbed_unique_taxon_name
376
   FROM taxon_match
377
  WHERE (taxon_match."Selected" = 'true'::text);
378

    
379

    
380
--
381
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
382
--
383

    
384
COMMENT ON VIEW taxon_best_match IS '
385
to modify:
386
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
387
SELECT __
388
$$);
389
';
390

    
391

    
392
--
393
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
394
--
395

    
396
CREATE VIEW "MatchedTaxon" AS
397
 SELECT s."*batch",
398
    s.match_num,
399
    s."Name_number",
400
    s."concatenatedScientificName",
401
    s."Overall_score",
402
    s."matchedTaxonName",
403
    s."matchedTaxonRank",
404
    s."*Name_score",
405
    s."matchedScientificNameAuthorship",
406
    s."matchedScientificNameID",
407
    s."*Author_score",
408
    s.parsed_family,
409
    s."matchedFamilyConfidence_fraction",
410
    s."matchedFamily",
411
    s."matchedGenus",
412
    s."matchedGenusConfidence_fraction",
413
    s."matchedSpecificEpithet",
414
    s."matchedSpeciesConfidence_fraction",
415
    s."Infraspecific_rank",
416
    s."matchedInfraspecificEpithet",
417
    s."*Infraspecific_epithet_score",
418
    s."Infraspecific_rank_2",
419
    s."Infraspecific_epithet_2_matched",
420
    s."Infraspecific_epithet_2_score",
421
    s."identificationQualifier",
422
    s."morphospeciesSuffix",
423
    s."*taxonomicStatus",
424
    s.accepted_taxon_name_no_author,
425
    s.accepted_author,
426
    s.accepted_taxon_rank,
427
    s."acceptedScientificNameID",
428
    s.accepted_species_binomial,
429
    s.accepted_family,
430
    s."*Selected",
431
    s."*Source",
432
    s."*Warnings",
433
    s."*Accepted_name_lsid",
434
    s.taxon_scrub__is_valid_match,
435
    s.scrubbed_unique_taxon_name,
436
    map_taxonomic_status(s."*taxonomicStatus", s.accepted_taxon_name_no_author) AS "taxonomicStatus",
437
        CASE
438
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
439
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
440
            ELSE s.accepted_species_binomial
441
        END AS accepted_morphospecies_binomial
442
   FROM ( SELECT taxon_best_match.batch AS "*batch",
443
            taxon_best_match.match_num,
444
            taxon_best_match."Name_number",
445
            taxon_best_match."Name_submitted" AS "concatenatedScientificName",
446
            taxon_best_match."Overall_score",
447
            taxon_best_match."Name_matched" AS "matchedTaxonName",
448
            taxon_best_match."Name_matched_rank" AS "matchedTaxonRank",
449
            taxon_best_match."Name_score" AS "*Name_score",
450
            taxon_best_match."Name_matched_author" AS "matchedScientificNameAuthorship",
451
            taxon_best_match."Name_matched_url" AS "matchedScientificNameID",
452
            taxon_best_match."Author_score" AS "*Author_score",
453
            taxon_best_match."Family_matched" AS parsed_family,
454
            taxon_best_match."Family_score" AS "matchedFamilyConfidence_fraction",
455
            taxon_best_match."Name_matched_accepted_family" AS "matchedFamily",
456
            taxon_best_match."Genus_matched" AS "matchedGenus",
457
            taxon_best_match."Genus_score" AS "matchedGenusConfidence_fraction",
458
            taxon_best_match."Specific_epithet_matched" AS "matchedSpecificEpithet",
459
            taxon_best_match."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction",
460
            taxon_best_match."Infraspecific_rank",
461
            taxon_best_match."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet",
462
            taxon_best_match."Infraspecific_epithet_score" AS "*Infraspecific_epithet_score",
463
            taxon_best_match."Infraspecific_rank_2",
464
            taxon_best_match."Infraspecific_epithet_2_matched",
465
            taxon_best_match."Infraspecific_epithet_2_score",
466
            taxon_best_match."Annotations" AS "identificationQualifier",
467
            taxon_best_match."Unmatched_terms" AS "morphospeciesSuffix",
468
            taxon_best_match."Taxonomic_status" AS "*taxonomicStatus",
469
            taxon_best_match."Accepted_name" AS accepted_taxon_name_no_author,
470
            taxon_best_match."Accepted_name_author" AS accepted_author,
471
            taxon_best_match."Accepted_name_rank" AS accepted_taxon_rank,
472
            taxon_best_match."Accepted_name_url" AS "acceptedScientificNameID",
473
            taxon_best_match."Accepted_name_species" AS accepted_species_binomial,
474
            taxon_best_match."Accepted_name_family" AS accepted_family,
475
            taxon_best_match."Selected" AS "*Selected",
476
            taxon_best_match."Source" AS "*Source",
477
            taxon_best_match."Warnings" AS "*Warnings",
478
            taxon_best_match."Accepted_name_lsid" AS "*Accepted_name_lsid",
479
            taxon_best_match.is_valid_match AS taxon_scrub__is_valid_match,
480
            taxon_best_match.scrubbed_unique_taxon_name
481
           FROM taxon_best_match) s;
482

    
483

    
484
--
485
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
486
--
487

    
488
COMMENT ON VIEW "MatchedTaxon" IS '
489
to modify:
490
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
491
SELECT __
492
$$);
493
';
494

    
495

    
496
--
497
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
498
--
499

    
500
CREATE VIEW "ValidMatchedTaxon" AS
501
 SELECT "MatchedTaxon"."*batch",
502
    "MatchedTaxon".match_num,
503
    "MatchedTaxon"."Name_number",
504
    "MatchedTaxon"."concatenatedScientificName",
505
    "MatchedTaxon"."Overall_score",
506
    "MatchedTaxon"."matchedTaxonName",
507
    "MatchedTaxon"."matchedTaxonRank",
508
    "MatchedTaxon"."*Name_score",
509
    "MatchedTaxon"."matchedScientificNameAuthorship",
510
    "MatchedTaxon"."matchedScientificNameID",
511
    "MatchedTaxon"."*Author_score",
512
    "MatchedTaxon".parsed_family,
513
    "MatchedTaxon"."matchedFamilyConfidence_fraction",
514
    "MatchedTaxon"."matchedFamily",
515
    "MatchedTaxon"."matchedGenus",
516
    "MatchedTaxon"."matchedGenusConfidence_fraction",
517
    "MatchedTaxon"."matchedSpecificEpithet",
518
    "MatchedTaxon"."matchedSpeciesConfidence_fraction",
519
    "MatchedTaxon"."Infraspecific_rank",
520
    "MatchedTaxon"."matchedInfraspecificEpithet",
521
    "MatchedTaxon"."*Infraspecific_epithet_score",
522
    "MatchedTaxon"."Infraspecific_rank_2",
523
    "MatchedTaxon"."Infraspecific_epithet_2_matched",
524
    "MatchedTaxon"."Infraspecific_epithet_2_score",
525
    "MatchedTaxon"."identificationQualifier",
526
    "MatchedTaxon"."morphospeciesSuffix",
527
    "MatchedTaxon"."*taxonomicStatus",
528
    "MatchedTaxon".accepted_taxon_name_no_author,
529
    "MatchedTaxon".accepted_author,
530
    "MatchedTaxon".accepted_taxon_rank,
531
    "MatchedTaxon"."acceptedScientificNameID",
532
    "MatchedTaxon".accepted_species_binomial,
533
    "MatchedTaxon".accepted_family,
534
    "MatchedTaxon"."*Selected",
535
    "MatchedTaxon"."*Source",
536
    "MatchedTaxon"."*Warnings",
537
    "MatchedTaxon"."*Accepted_name_lsid",
538
    "MatchedTaxon".taxon_scrub__is_valid_match,
539
    "MatchedTaxon".scrubbed_unique_taxon_name,
540
    "MatchedTaxon"."taxonomicStatus",
541
    "MatchedTaxon".accepted_morphospecies_binomial
542
   FROM "MatchedTaxon"
543
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
544

    
545

    
546
--
547
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
548
--
549

    
550
COMMENT ON VIEW "ValidMatchedTaxon" IS '
551
to update, use * as the column list
552
';
553

    
554

    
555
--
556
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
557
--
558

    
559
CREATE TABLE batch (
560
    id text NOT NULL,
561
    id_by_time text,
562
    time_submitted timestamp with time zone DEFAULT now(),
563
    client_version text
564
);
565

    
566

    
567
--
568
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
569
--
570

    
571
CREATE TABLE batch_download_settings (
572
    id text NOT NULL,
573
    "E-mail" text,
574
    "Id" text,
575
    "Job type" text,
576
    "Contains Id" boolean,
577
    "Start time" text,
578
    "Finish time" text,
579
    "TNRS version" text,
580
    "Sources selected" text,
581
    "Match threshold" double precision,
582
    "Classification" text,
583
    "Allow partial matches?" boolean,
584
    "Sort by source" boolean,
585
    "Constrain by higher taxonomy" boolean
586
);
587

    
588

    
589
--
590
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
591
--
592

    
593
COMMENT ON TABLE batch_download_settings IS '
594
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
595
';
596

    
597

    
598
--
599
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
600
--
601

    
602
CREATE TABLE client_version (
603
    id text NOT NULL,
604
    global_rev integer NOT NULL,
605
    "/lib/tnrs.py rev" integer,
606
    "/bin/tnrs_db rev" integer
607
);
608

    
609

    
610
--
611
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
612
--
613

    
614
COMMENT ON TABLE client_version IS '
615
contains svn revisions
616
';
617

    
618

    
619
--
620
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
621
--
622

    
623
COMMENT ON COLUMN client_version.global_rev IS '
624
from `svn info .` > Last Changed Rev
625
';
626

    
627

    
628
--
629
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
630
--
631

    
632
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
633
from `svn info lib/tnrs.py` > Last Changed Rev
634
';
635

    
636

    
637
--
638
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
639
--
640

    
641
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
642
from `svn info bin/tnrs_db` > Last Changed Rev
643
';
644

    
645

    
646
--
647
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
648
--
649

    
650
CREATE VIEW taxon_match_input AS
651
 SELECT taxon_match."Name_number",
652
    taxon_match."Name_submitted",
653
    taxon_match."Overall_score",
654
    taxon_match."Name_matched",
655
    taxon_match."Name_matched_rank",
656
    taxon_match."Name_score",
657
    taxon_match."Name_matched_author",
658
    taxon_match."Name_matched_url",
659
    taxon_match."Author_matched",
660
    taxon_match."Author_score",
661
    taxon_match."Family_matched",
662
    taxon_match."Family_score",
663
    taxon_match."Name_matched_accepted_family",
664
    taxon_match."Genus_matched",
665
    taxon_match."Genus_score",
666
    taxon_match."Specific_epithet_matched",
667
    taxon_match."Specific_epithet_score",
668
    taxon_match."Infraspecific_rank",
669
    taxon_match."Infraspecific_epithet_matched",
670
    taxon_match."Infraspecific_epithet_score",
671
    taxon_match."Infraspecific_rank_2",
672
    taxon_match."Infraspecific_epithet_2_matched",
673
    taxon_match."Infraspecific_epithet_2_score",
674
    taxon_match."Annotations",
675
    taxon_match."Unmatched_terms",
676
    taxon_match."Taxonomic_status",
677
    taxon_match."Accepted_name",
678
    taxon_match."Accepted_name_author",
679
    taxon_match."Accepted_name_rank",
680
    taxon_match."Accepted_name_url",
681
    taxon_match."Accepted_name_species",
682
    taxon_match."Accepted_name_family",
683
    taxon_match."Selected",
684
    taxon_match."Source",
685
    taxon_match."Warnings",
686
    taxon_match."Accepted_name_lsid"
687
   FROM taxon_match;
688

    
689

    
690
--
691
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
692
--
693

    
694
CREATE TABLE taxon_match_input__copy_to (
695
    "Name_number" integer,
696
    "Name_submitted" text,
697
    "Overall_score" double precision,
698
    "Name_matched" text,
699
    "Name_matched_rank" text,
700
    "Name_score" double precision,
701
    "Name_matched_author" text,
702
    "Name_matched_url" text,
703
    "Author_matched" text,
704
    "Author_score" double precision,
705
    "Family_matched" text,
706
    "Family_score" double precision,
707
    "Name_matched_accepted_family" text,
708
    "Genus_matched" text,
709
    "Genus_score" double precision,
710
    "Specific_epithet_matched" text,
711
    "Specific_epithet_score" double precision,
712
    "Infraspecific_rank" text,
713
    "Infraspecific_epithet_matched" text,
714
    "Infraspecific_epithet_score" double precision,
715
    "Infraspecific_rank_2" text,
716
    "Infraspecific_epithet_2_matched" text,
717
    "Infraspecific_epithet_2_score" double precision,
718
    "Annotations" text,
719
    "Unmatched_terms" text,
720
    "Taxonomic_status" text,
721
    "Accepted_name" text,
722
    "Accepted_name_author" text,
723
    "Accepted_name_rank" text,
724
    "Accepted_name_url" text,
725
    "Accepted_name_species" text,
726
    "Accepted_name_family" text,
727
    "Selected" text,
728
    "Source" text,
729
    "Warnings" text,
730
    "Accepted_name_lsid" text
731
);
732

    
733

    
734
--
735
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
736
--
737

    
738
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
739
 SELECT taxon_match."Name_submitted" AS scrubbed_unique_taxon_name,
740
    taxon_match."Name_matched_rank" AS scrubbed_taxon_rank,
741
    COALESCE(taxon_match."Name_matched_accepted_family", taxon_match."Family_matched") AS scrubbed_family,
742
    taxon_match."Genus_matched" AS scrubbed_genus,
743
    taxon_match."Specific_epithet_matched" AS scrubbed_specific_epithet,
744
    taxon_match."Infraspecific_rank" AS scrubbed_infraspecific_rank,
745
    taxon_match."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
746
    taxon_match."Name_matched_author" AS scrubbed_author,
747
    taxon_match."Name_matched" AS scrubbed_taxon_name_no_author,
748
    (taxon_match."Name_matched" || COALESCE((' '::text || taxon_match."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
749
   FROM taxon_match;
750

    
751

    
752
--
753
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
754
--
755

    
756
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
757
to modify:
758
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
759
SELECT __
760
$$);
761

    
762
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.
763
';
764

    
765

    
766
--
767
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
768
--
769

    
770
CREATE VIEW taxon_scrub AS
771
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
772
    "ValidMatchedTaxon"."*batch",
773
    "ValidMatchedTaxon".match_num,
774
    "ValidMatchedTaxon"."Name_number",
775
    "ValidMatchedTaxon"."concatenatedScientificName",
776
    "ValidMatchedTaxon"."Overall_score",
777
    "ValidMatchedTaxon"."matchedTaxonName",
778
    "ValidMatchedTaxon"."matchedTaxonRank",
779
    "ValidMatchedTaxon"."*Name_score",
780
    "ValidMatchedTaxon"."matchedScientificNameAuthorship",
781
    "ValidMatchedTaxon"."matchedScientificNameID",
782
    "ValidMatchedTaxon"."*Author_score",
783
    "ValidMatchedTaxon".parsed_family,
784
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction",
785
    "ValidMatchedTaxon"."matchedFamily",
786
    "ValidMatchedTaxon"."matchedGenus",
787
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction",
788
    "ValidMatchedTaxon"."matchedSpecificEpithet",
789
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction",
790
    "ValidMatchedTaxon"."Infraspecific_rank",
791
    "ValidMatchedTaxon"."matchedInfraspecificEpithet",
792
    "ValidMatchedTaxon"."*Infraspecific_epithet_score",
793
    "ValidMatchedTaxon"."Infraspecific_rank_2",
794
    "ValidMatchedTaxon"."Infraspecific_epithet_2_matched",
795
    "ValidMatchedTaxon"."Infraspecific_epithet_2_score",
796
    "ValidMatchedTaxon"."identificationQualifier",
797
    "ValidMatchedTaxon"."morphospeciesSuffix",
798
    "ValidMatchedTaxon"."*taxonomicStatus",
799
    "ValidMatchedTaxon".accepted_taxon_name_no_author,
800
    "ValidMatchedTaxon".accepted_author,
801
    "ValidMatchedTaxon".accepted_taxon_rank,
802
    "ValidMatchedTaxon"."acceptedScientificNameID",
803
    "ValidMatchedTaxon".accepted_species_binomial,
804
    "ValidMatchedTaxon".accepted_family,
805
    "ValidMatchedTaxon"."*Selected",
806
    "ValidMatchedTaxon"."*Source",
807
    "ValidMatchedTaxon"."*Warnings",
808
    "ValidMatchedTaxon"."*Accepted_name_lsid",
809
    "ValidMatchedTaxon".taxon_scrub__is_valid_match,
810
    "ValidMatchedTaxon"."taxonomicStatus",
811
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
812
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
813
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
814
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
815
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
816
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
817
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
818
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
819
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
820
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
821
        CASE
822
            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"."morphospeciesSuffix")
823
            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"."morphospeciesSuffix")
824
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
825
        END AS scrubbed_morphospecies_binomial
826
   FROM ("ValidMatchedTaxon"
827
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
828

    
829

    
830
--
831
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
832
--
833

    
834
COMMENT ON VIEW taxon_scrub IS '
835
to modify:
836
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
837
SELECT __
838
$$);
839
';
840

    
841

    
842
--
843
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
844
--
845

    
846
ALTER TABLE ONLY batch_download_settings
847
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
848

    
849

    
850
--
851
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
852
--
853

    
854
ALTER TABLE ONLY batch
855
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
856

    
857

    
858
--
859
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
860
--
861

    
862
ALTER TABLE ONLY batch
863
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
864

    
865

    
866
--
867
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
868
--
869

    
870
ALTER TABLE ONLY client_version
871
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
872

    
873

    
874
--
875
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
876
--
877

    
878
ALTER TABLE ONLY taxon_match
879
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
880

    
881

    
882
--
883
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
884
--
885

    
886
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
887

    
888

    
889
--
890
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
891
--
892

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

    
895

    
896
--
897
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
898
--
899

    
900
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("Name_submitted");
901

    
902

    
903
--
904
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
905
--
906

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

    
909

    
910
--
911
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
912
--
913

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

    
916

    
917
--
918
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
919
--
920

    
921
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
922

    
923

    
924
--
925
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
926
--
927

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

    
930

    
931
--
932
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
933
--
934

    
935
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
936

    
937

    
938
--
939
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
940
--
941

    
942
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();
943

    
944

    
945
--
946
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
947
--
948

    
949
ALTER TABLE ONLY batch
950
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
951

    
952

    
953
--
954
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
955
--
956

    
957
ALTER TABLE ONLY batch_download_settings
958
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
959

    
960

    
961
--
962
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
963
--
964

    
965
ALTER TABLE ONLY taxon_match
966
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
967

    
968

    
969
--
970
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
971
--
972

    
973
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
974
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
975
GRANT ALL ON SCHEMA "TNRS" TO bien;
976
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
977

    
978

    
979
--
980
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
981
--
982

    
983
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
984
REVOKE ALL ON TABLE taxon_match FROM bien;
985
GRANT ALL ON TABLE taxon_match TO bien;
986
GRANT SELECT ON TABLE taxon_match TO bien_read;
987

    
988

    
989
--
990
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
991
--
992

    
993
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
994
REVOKE ALL ON TABLE taxon_best_match FROM bien;
995
GRANT ALL ON TABLE taxon_best_match TO bien;
996
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
997

    
998

    
999
--
1000
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1001
--
1002

    
1003
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
1004
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
1005
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
1006
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
1007

    
1008

    
1009
--
1010
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1011
--
1012

    
1013
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
1014
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
1015
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
1016
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
1017

    
1018

    
1019
--
1020
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
1021
--
1022

    
1023
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
1024
REVOKE ALL ON TABLE taxon_match_input FROM bien;
1025
GRANT ALL ON TABLE taxon_match_input TO bien;
1026
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
1027

    
1028

    
1029
--
1030
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
1031
--
1032

    
1033
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
1034
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
1035
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1036
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1037

    
1038

    
1039
--
1040
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1041
--
1042

    
1043
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1044
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1045
GRANT ALL ON TABLE taxon_scrub TO bien;
1046
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1047

    
1048

    
1049
--
1050
-- PostgreSQL database dump complete
1051
--
1052

    
(7-7/9)