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."*Name_matched.batch",
398
    s."concatenatedScientificName",
399
    s."matchedTaxonName",
400
    s."matchedTaxonRank",
401
    s."*Name_matched.Name_score",
402
    s."matchedScientificNameAuthorship",
403
    s."matchedScientificNameID",
404
    s."*Name_matched.Author_score",
405
    s."matchedFamilyConfidence_fraction",
406
    s."matchedFamily",
407
    s."matchedGenus",
408
    s."matchedGenusConfidence_fraction",
409
    s."matchedSpecificEpithet",
410
    s."matchedSpeciesConfidence_fraction",
411
    s."matchedInfraspecificEpithet",
412
    s."*Name_matched.Infraspecific_epithet_score",
413
    s."identificationQualifier",
414
    s."morphospeciesSuffix",
415
    s."taxonomicStatus",
416
    s.accepted_taxon_name_no_author,
417
    s.accepted_author,
418
    s.accepted_taxon_rank,
419
    s."acceptedScientificNameID",
420
    s.accepted_species_binomial,
421
    s.accepted_family,
422
    s."*Name_matched.Selected",
423
    s."*Name_matched.Source",
424
    s."*Name_matched.Warnings",
425
    s."*Name_matched.Accepted_name_lsid",
426
    s.taxon_scrub__is_valid_match,
427
    s.scrubbed_unique_taxon_name,
428
        CASE
429
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
430
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
431
            ELSE s.accepted_species_binomial
432
        END AS accepted_morphospecies_binomial
433
   FROM ( SELECT taxon_best_match.batch AS "*Name_matched.batch",
434
            taxon_best_match."Name_submitted" AS "concatenatedScientificName",
435
            taxon_best_match."Name_matched" AS "matchedTaxonName",
436
            taxon_best_match."Name_matched_rank" AS "matchedTaxonRank",
437
            taxon_best_match."Name_score" AS "*Name_matched.Name_score",
438
            taxon_best_match."Name_matched_author" AS "matchedScientificNameAuthorship",
439
            taxon_best_match."Name_matched_url" AS "matchedScientificNameID",
440
            taxon_best_match."Author_score" AS "*Name_matched.Author_score",
441
            taxon_best_match."Family_score" AS "matchedFamilyConfidence_fraction",
442
            taxon_best_match."Name_matched_accepted_family" AS "matchedFamily",
443
            taxon_best_match."Genus_matched" AS "matchedGenus",
444
            taxon_best_match."Genus_score" AS "matchedGenusConfidence_fraction",
445
            taxon_best_match."Specific_epithet_matched" AS "matchedSpecificEpithet",
446
            taxon_best_match."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction",
447
            taxon_best_match."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet",
448
            taxon_best_match."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score",
449
            taxon_best_match."Annotations" AS "identificationQualifier",
450
            taxon_best_match."Unmatched_terms" AS "morphospeciesSuffix",
451
            map_taxonomic_status(taxon_best_match."Taxonomic_status", taxon_best_match."Accepted_name") AS "taxonomicStatus",
452
            taxon_best_match."Accepted_name" AS accepted_taxon_name_no_author,
453
            taxon_best_match."Accepted_name_author" AS accepted_author,
454
            taxon_best_match."Accepted_name_rank" AS accepted_taxon_rank,
455
            taxon_best_match."Accepted_name_url" AS "acceptedScientificNameID",
456
            taxon_best_match."Accepted_name_species" AS accepted_species_binomial,
457
            taxon_best_match."Accepted_name_family" AS accepted_family,
458
            taxon_best_match."Selected" AS "*Name_matched.Selected",
459
            taxon_best_match."Source" AS "*Name_matched.Source",
460
            taxon_best_match."Warnings" AS "*Name_matched.Warnings",
461
            taxon_best_match."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid",
462
            taxon_best_match.is_valid_match AS taxon_scrub__is_valid_match,
463
            taxon_best_match.scrubbed_unique_taxon_name
464
           FROM taxon_best_match) s;
465

    
466

    
467
--
468
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
469
--
470

    
471
COMMENT ON VIEW "MatchedTaxon" IS '
472
to modify:
473
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
474
SELECT __
475
$$);
476
';
477

    
478

    
479
--
480
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
481
--
482

    
483
CREATE VIEW "ValidMatchedTaxon" AS
484
 SELECT "MatchedTaxon"."*Name_matched.batch",
485
    "MatchedTaxon"."concatenatedScientificName",
486
    "MatchedTaxon"."matchedTaxonName",
487
    "MatchedTaxon"."matchedTaxonRank",
488
    "MatchedTaxon"."*Name_matched.Name_score",
489
    "MatchedTaxon"."matchedScientificNameAuthorship",
490
    "MatchedTaxon"."matchedScientificNameID",
491
    "MatchedTaxon"."*Name_matched.Author_score",
492
    "MatchedTaxon"."matchedFamilyConfidence_fraction",
493
    "MatchedTaxon"."matchedFamily",
494
    "MatchedTaxon"."matchedGenus",
495
    "MatchedTaxon"."matchedGenusConfidence_fraction",
496
    "MatchedTaxon"."matchedSpecificEpithet",
497
    "MatchedTaxon"."matchedSpeciesConfidence_fraction",
498
    "MatchedTaxon"."matchedInfraspecificEpithet",
499
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
500
    "MatchedTaxon"."identificationQualifier",
501
    "MatchedTaxon"."morphospeciesSuffix",
502
    "MatchedTaxon"."taxonomicStatus",
503
    "MatchedTaxon".accepted_taxon_name_no_author,
504
    "MatchedTaxon".accepted_author,
505
    "MatchedTaxon".accepted_taxon_rank,
506
    "MatchedTaxon"."acceptedScientificNameID",
507
    "MatchedTaxon".accepted_species_binomial,
508
    "MatchedTaxon".accepted_family,
509
    "MatchedTaxon"."*Name_matched.Selected",
510
    "MatchedTaxon"."*Name_matched.Source",
511
    "MatchedTaxon"."*Name_matched.Warnings",
512
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid",
513
    "MatchedTaxon".taxon_scrub__is_valid_match,
514
    "MatchedTaxon".scrubbed_unique_taxon_name,
515
    "MatchedTaxon".accepted_morphospecies_binomial
516
   FROM "MatchedTaxon"
517
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
518

    
519

    
520
--
521
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
522
--
523

    
524
COMMENT ON VIEW "ValidMatchedTaxon" IS '
525
to update, use * as the column list
526
';
527

    
528

    
529
--
530
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
531
--
532

    
533
CREATE TABLE batch (
534
    id text NOT NULL,
535
    id_by_time text,
536
    time_submitted timestamp with time zone DEFAULT now(),
537
    client_version text
538
);
539

    
540

    
541
--
542
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
543
--
544

    
545
CREATE TABLE batch_download_settings (
546
    id text NOT NULL,
547
    "E-mail" text,
548
    "Id" text,
549
    "Job type" text,
550
    "Contains Id" boolean,
551
    "Start time" text,
552
    "Finish time" text,
553
    "TNRS version" text,
554
    "Sources selected" text,
555
    "Match threshold" double precision,
556
    "Classification" text,
557
    "Allow partial matches?" boolean,
558
    "Sort by source" boolean,
559
    "Constrain by higher taxonomy" boolean
560
);
561

    
562

    
563
--
564
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
565
--
566

    
567
COMMENT ON TABLE batch_download_settings IS '
568
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
569
';
570

    
571

    
572
--
573
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
574
--
575

    
576
CREATE TABLE client_version (
577
    id text NOT NULL,
578
    global_rev integer NOT NULL,
579
    "/lib/tnrs.py rev" integer,
580
    "/bin/tnrs_db rev" integer
581
);
582

    
583

    
584
--
585
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
586
--
587

    
588
COMMENT ON TABLE client_version IS '
589
contains svn revisions
590
';
591

    
592

    
593
--
594
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
595
--
596

    
597
COMMENT ON COLUMN client_version.global_rev IS '
598
from `svn info .` > Last Changed Rev
599
';
600

    
601

    
602
--
603
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
604
--
605

    
606
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
607
from `svn info lib/tnrs.py` > Last Changed Rev
608
';
609

    
610

    
611
--
612
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
613
--
614

    
615
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
616
from `svn info bin/tnrs_db` > Last Changed Rev
617
';
618

    
619

    
620
--
621
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
622
--
623

    
624
CREATE VIEW taxon_match_input AS
625
 SELECT taxon_match."Name_number",
626
    taxon_match."Name_submitted",
627
    taxon_match."Overall_score",
628
    taxon_match."Name_matched",
629
    taxon_match."Name_matched_rank",
630
    taxon_match."Name_score",
631
    taxon_match."Name_matched_author",
632
    taxon_match."Name_matched_url",
633
    taxon_match."Author_matched",
634
    taxon_match."Author_score",
635
    taxon_match."Family_matched",
636
    taxon_match."Family_score",
637
    taxon_match."Name_matched_accepted_family",
638
    taxon_match."Genus_matched",
639
    taxon_match."Genus_score",
640
    taxon_match."Specific_epithet_matched",
641
    taxon_match."Specific_epithet_score",
642
    taxon_match."Infraspecific_rank",
643
    taxon_match."Infraspecific_epithet_matched",
644
    taxon_match."Infraspecific_epithet_score",
645
    taxon_match."Infraspecific_rank_2",
646
    taxon_match."Infraspecific_epithet_2_matched",
647
    taxon_match."Infraspecific_epithet_2_score",
648
    taxon_match."Annotations",
649
    taxon_match."Unmatched_terms",
650
    taxon_match."Taxonomic_status",
651
    taxon_match."Accepted_name",
652
    taxon_match."Accepted_name_author",
653
    taxon_match."Accepted_name_rank",
654
    taxon_match."Accepted_name_url",
655
    taxon_match."Accepted_name_species",
656
    taxon_match."Accepted_name_family",
657
    taxon_match."Selected",
658
    taxon_match."Source",
659
    taxon_match."Warnings",
660
    taxon_match."Accepted_name_lsid"
661
   FROM taxon_match;
662

    
663

    
664
--
665
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
666
--
667

    
668
CREATE TABLE taxon_match_input__copy_to (
669
    "Name_number" integer,
670
    "Name_submitted" text,
671
    "Overall_score" double precision,
672
    "Name_matched" text,
673
    "Name_matched_rank" text,
674
    "Name_score" double precision,
675
    "Name_matched_author" text,
676
    "Name_matched_url" text,
677
    "Author_matched" text,
678
    "Author_score" double precision,
679
    "Family_matched" text,
680
    "Family_score" double precision,
681
    "Name_matched_accepted_family" text,
682
    "Genus_matched" text,
683
    "Genus_score" double precision,
684
    "Specific_epithet_matched" text,
685
    "Specific_epithet_score" double precision,
686
    "Infraspecific_rank" text,
687
    "Infraspecific_epithet_matched" text,
688
    "Infraspecific_epithet_score" double precision,
689
    "Infraspecific_rank_2" text,
690
    "Infraspecific_epithet_2_matched" text,
691
    "Infraspecific_epithet_2_score" double precision,
692
    "Annotations" text,
693
    "Unmatched_terms" text,
694
    "Taxonomic_status" text,
695
    "Accepted_name" text,
696
    "Accepted_name_author" text,
697
    "Accepted_name_rank" text,
698
    "Accepted_name_url" text,
699
    "Accepted_name_species" text,
700
    "Accepted_name_family" text,
701
    "Selected" text,
702
    "Source" text,
703
    "Warnings" text,
704
    "Accepted_name_lsid" text
705
);
706

    
707

    
708
--
709
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
710
--
711

    
712
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
713
 SELECT taxon_match."Name_submitted" AS scrubbed_unique_taxon_name,
714
    taxon_match."Name_matched_rank" AS scrubbed_taxon_rank,
715
    COALESCE(taxon_match."Name_matched_accepted_family", taxon_match."Family_matched") AS scrubbed_family,
716
    taxon_match."Genus_matched" AS scrubbed_genus,
717
    taxon_match."Specific_epithet_matched" AS scrubbed_specific_epithet,
718
    taxon_match."Infraspecific_rank" AS scrubbed_infraspecific_rank,
719
    taxon_match."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
720
    taxon_match."Name_matched_author" AS scrubbed_author,
721
    taxon_match."Name_matched" AS scrubbed_taxon_name_no_author,
722
    (taxon_match."Name_matched" || COALESCE((' '::text || taxon_match."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
723
   FROM taxon_match;
724

    
725

    
726
--
727
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
728
--
729

    
730
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
731
to modify:
732
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
733
SELECT __
734
$$);
735

    
736
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.
737
';
738

    
739

    
740
--
741
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
742
--
743

    
744
CREATE VIEW taxon_scrub AS
745
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
746
    "ValidMatchedTaxon"."*Name_matched.batch",
747
    "ValidMatchedTaxon"."concatenatedScientificName",
748
    "ValidMatchedTaxon"."matchedTaxonName",
749
    "ValidMatchedTaxon"."matchedTaxonRank",
750
    "ValidMatchedTaxon"."*Name_matched.Name_score",
751
    "ValidMatchedTaxon"."matchedScientificNameAuthorship",
752
    "ValidMatchedTaxon"."matchedScientificNameID",
753
    "ValidMatchedTaxon"."*Name_matched.Author_score",
754
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction",
755
    "ValidMatchedTaxon"."matchedFamily",
756
    "ValidMatchedTaxon"."matchedGenus",
757
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction",
758
    "ValidMatchedTaxon"."matchedSpecificEpithet",
759
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction",
760
    "ValidMatchedTaxon"."matchedInfraspecificEpithet",
761
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
762
    "ValidMatchedTaxon"."identificationQualifier",
763
    "ValidMatchedTaxon"."morphospeciesSuffix",
764
    "ValidMatchedTaxon"."taxonomicStatus",
765
    "ValidMatchedTaxon".accepted_taxon_name_no_author,
766
    "ValidMatchedTaxon".accepted_author,
767
    "ValidMatchedTaxon".accepted_taxon_rank,
768
    "ValidMatchedTaxon"."acceptedScientificNameID",
769
    "ValidMatchedTaxon".accepted_species_binomial,
770
    "ValidMatchedTaxon".accepted_family,
771
    "ValidMatchedTaxon"."*Name_matched.Selected",
772
    "ValidMatchedTaxon"."*Name_matched.Source",
773
    "ValidMatchedTaxon"."*Name_matched.Warnings",
774
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid",
775
    "ValidMatchedTaxon".taxon_scrub__is_valid_match,
776
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
777
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
778
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
779
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
780
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
781
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
782
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
783
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
784
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
785
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
786
        CASE
787
            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")
788
            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")
789
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
790
        END AS scrubbed_morphospecies_binomial
791
   FROM ("ValidMatchedTaxon"
792
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
793

    
794

    
795
--
796
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
797
--
798

    
799
COMMENT ON VIEW taxon_scrub IS '
800
to modify:
801
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
802
SELECT __
803
$$);
804
';
805

    
806

    
807
--
808
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
809
--
810

    
811
ALTER TABLE ONLY batch_download_settings
812
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
813

    
814

    
815
--
816
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
817
--
818

    
819
ALTER TABLE ONLY batch
820
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
821

    
822

    
823
--
824
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
825
--
826

    
827
ALTER TABLE ONLY batch
828
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
829

    
830

    
831
--
832
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
833
--
834

    
835
ALTER TABLE ONLY client_version
836
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
837

    
838

    
839
--
840
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
841
--
842

    
843
ALTER TABLE ONLY taxon_match
844
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
845

    
846

    
847
--
848
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
849
--
850

    
851
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
852

    
853

    
854
--
855
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
856
--
857

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

    
860

    
861
--
862
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
863
--
864

    
865
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("Name_submitted");
866

    
867

    
868
--
869
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
870
--
871

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

    
874

    
875
--
876
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
877
--
878

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

    
881

    
882
--
883
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
884
--
885

    
886
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
887

    
888

    
889
--
890
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
891
--
892

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

    
895

    
896
--
897
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
898
--
899

    
900
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
901

    
902

    
903
--
904
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
905
--
906

    
907
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();
908

    
909

    
910
--
911
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
912
--
913

    
914
ALTER TABLE ONLY batch
915
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
916

    
917

    
918
--
919
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
920
--
921

    
922
ALTER TABLE ONLY batch_download_settings
923
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
924

    
925

    
926
--
927
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
928
--
929

    
930
ALTER TABLE ONLY taxon_match
931
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
932

    
933

    
934
--
935
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
936
--
937

    
938
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
939
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
940
GRANT ALL ON SCHEMA "TNRS" TO bien;
941
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
942

    
943

    
944
--
945
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
946
--
947

    
948
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
949
REVOKE ALL ON TABLE taxon_match FROM bien;
950
GRANT ALL ON TABLE taxon_match TO bien;
951
GRANT SELECT ON TABLE taxon_match TO bien_read;
952

    
953

    
954
--
955
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
956
--
957

    
958
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
959
REVOKE ALL ON TABLE taxon_best_match FROM bien;
960
GRANT ALL ON TABLE taxon_best_match TO bien;
961
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
962

    
963

    
964
--
965
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
966
--
967

    
968
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
969
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
970
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
971
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
972

    
973

    
974
--
975
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
976
--
977

    
978
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
979
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
980
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
981
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
982

    
983

    
984
--
985
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
986
--
987

    
988
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
989
REVOKE ALL ON TABLE taxon_match_input FROM bien;
990
GRANT ALL ON TABLE taxon_match_input TO bien;
991
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
992

    
993

    
994
--
995
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
996
--
997

    
998
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
999
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
1000
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1001
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1002

    
1003

    
1004
--
1005
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1006
--
1007

    
1008
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1009
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1010
GRANT ALL ON TABLE taxon_scrub TO bien;
1011
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1012

    
1013

    
1014
--
1015
-- PostgreSQL database dump complete
1016
--
1017

    
(8-8/10)