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".tnrs'', 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: MatchedTaxon_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
46
--
47

    
48
CREATE FUNCTION "MatchedTaxon_modify"(view_query text DEFAULT NULL::text) RETURNS void
49
    LANGUAGE sql
50
    AS $_$
51
SELECT util.recreate_view('"TNRS"."MatchedTaxon"', $1, $$
52
-- **IMPORTANT**: keep these updated as described in the views' comments
53

    
54
CREATE VIEW "TNRS"."ValidMatchedTaxon" AS 
55
 SELECT *
56
   FROM "TNRS"."MatchedTaxon"
57
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
58
$$||util.mk_set_relation_metadata('"TNRS"."ValidMatchedTaxon"')||$$
59

    
60
CREATE VIEW "TNRS".taxon_scrub AS 
61
 SELECT *, 
62
        CASE
63
            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")
64
            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")
65
            ELSE ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet
66
        END AS scrubbed_morphospecies_binomial
67
   FROM "TNRS"."ValidMatchedTaxon"
68
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
69
$$||util.mk_set_relation_metadata('"TNRS".taxon_scrub')||$$
70
$$);
71
$_$;
72

    
73

    
74
--
75
-- Name: FUNCTION "MatchedTaxon_modify"(view_query text); Type: COMMENT; Schema: TNRS; Owner: -
76
--
77

    
78
COMMENT ON FUNCTION "MatchedTaxon_modify"(view_query text) IS '
79
usage:
80
SELECT "TNRS"."MatchedTaxon_modify"($$
81
 SELECT *, __ AS accepted_morphospecies_binomial
82
   FROM __
83
$$);
84

    
85
idempotent
86
';
87

    
88

    
89
--
90
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
91
--
92

    
93
CREATE FUNCTION batch__fill() RETURNS trigger
94
    LANGUAGE plpgsql
95
    AS $$
96
BEGIN
97
	new.id_by_time = new.time_submitted;
98
	new.id = COALESCE(new.id, new.id_by_time);
99
	RETURN new;
100
END;
101
$$;
102

    
103

    
104
--
105
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
106
--
107

    
108
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
109
    LANGUAGE sql STABLE STRICT
110
    AS $_$
111
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
112
$_$;
113

    
114

    
115
--
116
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
117
--
118

    
119
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
120
    LANGUAGE sql STABLE STRICT
121
    AS $_$
122
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
123
$_$;
124

    
125

    
126
--
127
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
128
--
129

    
130
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
131
    LANGUAGE sql IMMUTABLE
132
    AS $_$
133
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
134
"taxonomic_status should be accepted instead of synonym when an accepted name is
135
available (this is not always the case when a name is marked as a synonym)" */
136
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
137
$_$;
138

    
139

    
140
--
141
-- Name: taxon_scrub_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
142
--
143

    
144
CREATE FUNCTION taxon_scrub_modify(view_query text DEFAULT NULL::text) RETURNS void
145
    LANGUAGE sql
146
    AS $_$
147
SELECT util.recreate_view('"TNRS".taxon_scrub', $1);
148
$_$;
149

    
150

    
151
--
152
-- Name: FUNCTION taxon_scrub_modify(view_query text); Type: COMMENT; Schema: TNRS; Owner: -
153
--
154

    
155
COMMENT ON FUNCTION taxon_scrub_modify(view_query text) IS '
156
usage:
157
SELECT "TNRS".taxon_scrub_modify($$
158
 SELECT *, __ AS scrubbed_morphospecies_binomial
159
   FROM "TNRS"."ValidMatchedTaxon"
160
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
161
$$);
162

    
163
idempotent
164
';
165

    
166

    
167
--
168
-- Name: tnrs__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
169
--
170

    
171
CREATE FUNCTION tnrs__batch_begin() RETURNS trigger
172
    LANGUAGE plpgsql
173
    AS $$
174
BEGIN
175
	PERFORM util.seq__reset('pg_temp.tnrs__match_num__seq', 0);
176
	RETURN NULL;
177
END;
178
$$;
179

    
180

    
181
--
182
-- Name: tnrs__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
183
--
184

    
185
CREATE FUNCTION tnrs__match_num__fill() RETURNS trigger
186
    LANGUAGE plpgsql
187
    AS $$
188
BEGIN
189
	IF new.match_num IS NULL THEN
190
		new.match_num = "TNRS".tnrs__match_num__next();
191
	END IF;
192
	RETURN new;
193
END;
194
$$;
195

    
196

    
197
--
198
-- Name: tnrs__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
199
--
200

    
201
CREATE FUNCTION tnrs__match_num__next() RETURNS bigint
202
    LANGUAGE sql
203
    AS $$
204
SELECT nextval('pg_temp.tnrs__match_num__seq');
205
$$;
206

    
207

    
208
--
209
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
210
--
211

    
212
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
213
    LANGUAGE plpgsql
214
    AS $$
215
DECLARE
216
	"Specific_epithet_is_plant" boolean :=
217
		(CASE
218
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
219
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
220
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
221
			THEN true
222
		ELSE NULL -- ambiguous
223
		END);
224
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
225
		-- author disambiguates
226
	family_is_homonym boolean = NOT never_homonym
227
		AND "TNRS".family_is_homonym(new."Family_matched");
228
	genus_is_homonym  boolean = NOT never_homonym
229
		AND "TNRS".genus_is_homonym(new."Genus_matched");
230
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
231
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
232
			new."Name_matched")
233
		, NULLIF(new."Name_matched", 'No suitable matches found.')
234
		, new."Name_matched_author"
235
		), '');
236
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
237
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
238
			new."Accepted_name")
239
		, new."Accepted_name"
240
		, new."Accepted_name_author"
241
		), '');
242
BEGIN
243
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
244
	a name, but the name is not meaningful because it is not unambiguous). */
245
	new.is_valid_match = new."Taxonomic_status" != 'Invalid'
246
		AND COALESCE(CASE
247
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
248
			THEN true
249
		ELSE -- consider genus
250
			(CASE
251
			WHEN new."Genus_score" =  1	   -- exact match
252
				THEN
253
				(CASE
254
				WHEN NOT genus_is_homonym THEN true
255
				ELSE "Specific_epithet_is_plant"
256
				END)
257
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
258
				THEN "Specific_epithet_is_plant"
259
			ELSE NULL -- ambiguous
260
			END)
261
		END, false);
262
	new.scrubbed_unique_taxon_name = COALESCE(
263
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
264
	
265
	RETURN new;
266
END;
267
$$;
268

    
269

    
270
--
271
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
272
--
273

    
274
COMMENT ON FUNCTION tnrs_populate_fields() IS '
275
IMPORTANT: when changing this function, you must regenerate the derived cols:
276
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
277
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
278
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
279
runtime: 1.5 min ("92633 ms")
280
';
281

    
282

    
283
SET default_tablespace = '';
284

    
285
SET default_with_oids = false;
286

    
287
--
288
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
289
--
290

    
291
CREATE TABLE tnrs (
292
    batch text DEFAULT now() NOT NULL,
293
    match_num integer NOT NULL,
294
    "Name_number" integer NOT NULL,
295
    "Name_submitted" text NOT NULL,
296
    "Overall_score" double precision,
297
    "Name_matched" text,
298
    "Name_matched_rank" text,
299
    "Name_score" double precision,
300
    "Name_matched_author" text,
301
    "Name_matched_url" text,
302
    "Author_matched" text,
303
    "Author_score" double precision,
304
    "Family_matched" text,
305
    "Family_score" double precision,
306
    "Name_matched_accepted_family" text,
307
    "Genus_matched" text,
308
    "Genus_score" double precision,
309
    "Specific_epithet_matched" text,
310
    "Specific_epithet_score" double precision,
311
    "Infraspecific_rank" text,
312
    "Infraspecific_epithet_matched" text,
313
    "Infraspecific_epithet_score" double precision,
314
    "Infraspecific_rank_2" text,
315
    "Infraspecific_epithet_2_matched" text,
316
    "Infraspecific_epithet_2_score" double precision,
317
    "Annotations" text,
318
    "Unmatched_terms" text,
319
    "Taxonomic_status" text,
320
    "Accepted_name" text,
321
    "Accepted_name_author" text,
322
    "Accepted_name_rank" text,
323
    "Accepted_name_url" text,
324
    "Accepted_name_species" text,
325
    "Accepted_name_family" text,
326
    "Selected" text,
327
    "Source" text,
328
    "Warnings" text,
329
    "Accepted_name_lsid" text,
330
    is_valid_match boolean NOT NULL,
331
    scrubbed_unique_taxon_name text
332
);
333

    
334

    
335
--
336
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
337
--
338

    
339
COMMENT ON TABLE tnrs IS '
340
to remove columns or add columns at the end:
341
$ rm=1 inputs/.TNRS/data.sql.run
342
$ make schemas/remake
343

    
344
to add columns in the middle:
345
make the changes in inputs/.TNRS/schema.sql
346
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
347
$ make schemas/remake
348

    
349
to populate a new column:
350
ALTER TABLE "TNRS".tnrs DISABLE TRIGGER tnrs_populate_fields; --speeds up update
351
UPDATE "TNRS".tnrs SET "col" = value;
352
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
353
ALTER TABLE "TNRS".tnrs ENABLE TRIGGER tnrs_populate_fields;
354
VACUUM ANALYZE "TNRS".tnrs --remove previous rows; runtime: 1.5 min ("92633 ms")
355

    
356
to add a constraint: runtime: 3 min ("173620 ms")
357
';
358

    
359

    
360
--
361
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
362
--
363

    
364
CREATE VIEW "MatchedTaxon" AS
365
 SELECT s."*Name_matched.batch", 
366
    s."concatenatedScientificName", 
367
    s."matchedTaxonName", 
368
    s."matchedTaxonRank", 
369
    s."*Name_matched.Name_score", 
370
    s."matchedScientificNameAuthorship", 
371
    s."matchedScientificNameID", 
372
    s."*Name_matched.Author_score", 
373
    s."matchedFamilyConfidence_fraction", 
374
    s."matchedFamily", 
375
    s."matchedGenus", 
376
    s."matchedGenusConfidence_fraction", 
377
    s."matchedSpecificEpithet", 
378
    s."matchedSpeciesConfidence_fraction", 
379
    s."matchedInfraspecificEpithet", 
380
    s."*Name_matched.Infraspecific_epithet_score", 
381
    s."identificationQualifier", 
382
    s."morphospeciesSuffix", 
383
    s."taxonomicStatus", 
384
    s.accepted_taxon_name_no_author, 
385
    s.accepted_author, 
386
    s.accepted_taxon_rank, 
387
    s."acceptedScientificNameID", 
388
    s.accepted_species_binomial, 
389
    s.accepted_family, 
390
    s."*Name_matched.Selected", 
391
    s."*Name_matched.Source", 
392
    s."*Name_matched.Warnings", 
393
    s."*Name_matched.Accepted_name_lsid", 
394
    s.taxon_scrub__is_valid_match, 
395
    s.scrubbed_unique_taxon_name, 
396
        CASE
397
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
398
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
399
            ELSE s.accepted_species_binomial
400
        END AS accepted_morphospecies_binomial
401
   FROM ( SELECT tnrs.batch AS "*Name_matched.batch", 
402
            tnrs."Name_submitted" AS "concatenatedScientificName", 
403
            tnrs."Name_matched" AS "matchedTaxonName", 
404
            tnrs."Name_matched_rank" AS "matchedTaxonRank", 
405
            tnrs."Name_score" AS "*Name_matched.Name_score", 
406
            tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", 
407
            tnrs."Name_matched_url" AS "matchedScientificNameID", 
408
            tnrs."Author_score" AS "*Name_matched.Author_score", 
409
            tnrs."Family_score" AS "matchedFamilyConfidence_fraction", 
410
            COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", 
411
            tnrs."Genus_matched" AS "matchedGenus", 
412
            tnrs."Genus_score" AS "matchedGenusConfidence_fraction", 
413
            tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", 
414
            tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", 
415
            tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", 
416
            tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", 
417
            tnrs."Annotations" AS "identificationQualifier", 
418
            tnrs."Unmatched_terms" AS "morphospeciesSuffix", 
419
            map_taxonomic_status(tnrs."Taxonomic_status", tnrs."Accepted_name") AS "taxonomicStatus", 
420
            tnrs."Accepted_name" AS accepted_taxon_name_no_author, 
421
            tnrs."Accepted_name_author" AS accepted_author, 
422
            tnrs."Accepted_name_rank" AS accepted_taxon_rank, 
423
            tnrs."Accepted_name_url" AS "acceptedScientificNameID", 
424
            tnrs."Accepted_name_species" AS accepted_species_binomial, 
425
            tnrs."Accepted_name_family" AS accepted_family, 
426
            tnrs."Selected" AS "*Name_matched.Selected", 
427
            tnrs."Source" AS "*Name_matched.Source", 
428
            tnrs."Warnings" AS "*Name_matched.Warnings", 
429
            tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", 
430
            tnrs.is_valid_match AS taxon_scrub__is_valid_match, 
431
            tnrs.scrubbed_unique_taxon_name
432
           FROM tnrs) s;
433

    
434

    
435
--
436
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
437
--
438

    
439
COMMENT ON VIEW "MatchedTaxon" IS '
440
to modify:
441
SELECT "TNRS"."MatchedTaxon_modify"($$
442
 SELECT *, __ AS accepted_morphospecies_binomial
443
   FROM __
444
$$);
445
';
446

    
447

    
448
--
449
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
450
--
451

    
452
CREATE VIEW "ValidMatchedTaxon" AS
453
 SELECT "MatchedTaxon"."*Name_matched.batch", 
454
    "MatchedTaxon"."concatenatedScientificName", 
455
    "MatchedTaxon"."matchedTaxonName", 
456
    "MatchedTaxon"."matchedTaxonRank", 
457
    "MatchedTaxon"."*Name_matched.Name_score", 
458
    "MatchedTaxon"."matchedScientificNameAuthorship", 
459
    "MatchedTaxon"."matchedScientificNameID", 
460
    "MatchedTaxon"."*Name_matched.Author_score", 
461
    "MatchedTaxon"."matchedFamilyConfidence_fraction", 
462
    "MatchedTaxon"."matchedFamily", 
463
    "MatchedTaxon"."matchedGenus", 
464
    "MatchedTaxon"."matchedGenusConfidence_fraction", 
465
    "MatchedTaxon"."matchedSpecificEpithet", 
466
    "MatchedTaxon"."matchedSpeciesConfidence_fraction", 
467
    "MatchedTaxon"."matchedInfraspecificEpithet", 
468
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
469
    "MatchedTaxon"."identificationQualifier", 
470
    "MatchedTaxon"."morphospeciesSuffix", 
471
    "MatchedTaxon"."taxonomicStatus", 
472
    "MatchedTaxon".accepted_taxon_name_no_author, 
473
    "MatchedTaxon".accepted_author, 
474
    "MatchedTaxon".accepted_taxon_rank, 
475
    "MatchedTaxon"."acceptedScientificNameID", 
476
    "MatchedTaxon".accepted_species_binomial, 
477
    "MatchedTaxon".accepted_family, 
478
    "MatchedTaxon"."*Name_matched.Selected", 
479
    "MatchedTaxon"."*Name_matched.Source", 
480
    "MatchedTaxon"."*Name_matched.Warnings", 
481
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid", 
482
    "MatchedTaxon".taxon_scrub__is_valid_match, 
483
    "MatchedTaxon".scrubbed_unique_taxon_name, 
484
    "MatchedTaxon".accepted_morphospecies_binomial
485
   FROM "MatchedTaxon"
486
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
487

    
488

    
489
--
490
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
491
--
492

    
493
COMMENT ON VIEW "ValidMatchedTaxon" IS '
494
to update, use * as the column list
495
';
496

    
497

    
498
--
499
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
500
--
501

    
502
CREATE TABLE batch (
503
    id text NOT NULL,
504
    id_by_time text,
505
    time_submitted timestamp with time zone DEFAULT now(),
506
    client_version text
507
);
508

    
509

    
510
--
511
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
512
--
513

    
514
CREATE TABLE batch_download_settings (
515
    id text NOT NULL,
516
    "E-mail" text,
517
    "Id" text,
518
    "Job type" text,
519
    "Contains Id" boolean,
520
    "Start time" text,
521
    "Finish time" text,
522
    "TNRS version" text,
523
    "Sources selected" text,
524
    "Match threshold" double precision,
525
    "Classification" text,
526
    "Allow partial matches?" boolean,
527
    "Sort by source" boolean,
528
    "Constrain by higher taxonomy" boolean
529
);
530

    
531

    
532
--
533
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
534
--
535

    
536
COMMENT ON TABLE batch_download_settings IS '
537
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
538
';
539

    
540

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

    
545
CREATE TABLE client_version (
546
    id text NOT NULL,
547
    global_rev integer NOT NULL,
548
    "/lib/tnrs.py rev" integer,
549
    "/bin/tnrs_db rev" integer
550
);
551

    
552

    
553
--
554
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
555
--
556

    
557
COMMENT ON TABLE client_version IS '
558
contains svn revisions
559
';
560

    
561

    
562
--
563
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
564
--
565

    
566
COMMENT ON COLUMN client_version.global_rev IS '
567
from `svn info .` > Last Changed Rev
568
';
569

    
570

    
571
--
572
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
573
--
574

    
575
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
576
from `svn info lib/tnrs.py` > Last Changed Rev
577
';
578

    
579

    
580
--
581
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
582
--
583

    
584
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
585
from `svn info bin/tnrs_db` > Last Changed Rev
586
';
587

    
588

    
589
--
590
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
591
--
592

    
593
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
594
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
595
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
596
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
597
    tnrs."Genus_matched" AS scrubbed_genus, 
598
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
599
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
600
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
601
    tnrs."Name_matched_author" AS scrubbed_author, 
602
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author, 
603
    (tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
604
   FROM tnrs;
605

    
606

    
607
--
608
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
609
--
610

    
611
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
612
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.
613
';
614

    
615

    
616
--
617
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
618
--
619

    
620
CREATE VIEW taxon_scrub AS
621
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
622
    "ValidMatchedTaxon"."*Name_matched.batch", 
623
    "ValidMatchedTaxon"."concatenatedScientificName", 
624
    "ValidMatchedTaxon"."matchedTaxonName", 
625
    "ValidMatchedTaxon"."matchedTaxonRank", 
626
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
627
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
628
    "ValidMatchedTaxon"."matchedScientificNameID", 
629
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
630
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
631
    "ValidMatchedTaxon"."matchedFamily", 
632
    "ValidMatchedTaxon"."matchedGenus", 
633
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
634
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
635
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
636
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
637
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
638
    "ValidMatchedTaxon"."identificationQualifier", 
639
    "ValidMatchedTaxon"."morphospeciesSuffix", 
640
    "ValidMatchedTaxon"."taxonomicStatus", 
641
    "ValidMatchedTaxon".accepted_taxon_name_no_author, 
642
    "ValidMatchedTaxon".accepted_author, 
643
    "ValidMatchedTaxon".accepted_taxon_rank, 
644
    "ValidMatchedTaxon"."acceptedScientificNameID", 
645
    "ValidMatchedTaxon".accepted_species_binomial, 
646
    "ValidMatchedTaxon".accepted_family, 
647
    "ValidMatchedTaxon"."*Name_matched.Selected", 
648
    "ValidMatchedTaxon"."*Name_matched.Source", 
649
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
650
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
651
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
652
    "ValidMatchedTaxon".accepted_morphospecies_binomial, 
653
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
654
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
655
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
656
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
657
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
658
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
659
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
660
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, 
661
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author, 
662
        CASE
663
            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")
664
            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")
665
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
666
        END AS scrubbed_morphospecies_binomial
667
   FROM ("ValidMatchedTaxon"
668
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
669

    
670

    
671
--
672
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
673
--
674

    
675
COMMENT ON VIEW taxon_scrub IS '
676
to modify:
677
SELECT "TNRS".taxon_scrub_modify($$
678
 SELECT *, __ AS scrubbed_morphospecies_binomial
679
   FROM "TNRS"."ValidMatchedTaxon"
680
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
681
$$);
682
';
683

    
684

    
685
--
686
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
687
--
688

    
689
ALTER TABLE ONLY batch_download_settings
690
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
691

    
692

    
693
--
694
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
695
--
696

    
697
ALTER TABLE ONLY batch
698
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
699

    
700

    
701
--
702
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
703
--
704

    
705
ALTER TABLE ONLY batch
706
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
707

    
708

    
709
--
710
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
711
--
712

    
713
ALTER TABLE ONLY client_version
714
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
715

    
716

    
717
--
718
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
719
--
720

    
721
ALTER TABLE ONLY tnrs
722
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, match_num);
723

    
724

    
725
--
726
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
727
--
728

    
729
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
730

    
731

    
732
--
733
-- Name: tnrs_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
734
--
735

    
736
CREATE INDEX "tnrs_Name_submitted_idx" ON tnrs USING btree ("Name_submitted");
737

    
738

    
739
--
740
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
741
--
742

    
743
CREATE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
744

    
745

    
746
--
747
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
748
--
749

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

    
752

    
753
--
754
-- Name: tnrs__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
755
--
756

    
757
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON tnrs FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
758

    
759

    
760
--
761
-- Name: tnrs__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
762
--
763

    
764
CREATE TRIGGER tnrs__match_num__fill BEFORE INSERT ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs__match_num__fill();
765

    
766

    
767
--
768
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
769
--
770

    
771
CREATE TRIGGER tnrs_populate_fields BEFORE INSERT OR UPDATE ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs_populate_fields();
772

    
773

    
774
--
775
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
776
--
777

    
778
ALTER TABLE ONLY batch
779
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
780

    
781

    
782
--
783
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
784
--
785

    
786
ALTER TABLE ONLY batch_download_settings
787
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
788

    
789

    
790
--
791
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
792
--
793

    
794
ALTER TABLE ONLY tnrs
795
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
796

    
797

    
798
--
799
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
800
--
801

    
802
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
803
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
804
GRANT ALL ON SCHEMA "TNRS" TO bien;
805
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
806

    
807

    
808
--
809
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
810
--
811

    
812
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
813
REVOKE ALL ON TABLE tnrs FROM bien;
814
GRANT ALL ON TABLE tnrs TO bien;
815
GRANT SELECT ON TABLE tnrs TO bien_read;
816

    
817

    
818
--
819
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
820
--
821

    
822
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
823
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
824
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
825
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
826

    
827

    
828
--
829
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
830
--
831

    
832
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
833
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
834
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
835
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
836

    
837

    
838
--
839
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
840
--
841

    
842
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
843
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
844
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
845
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
846

    
847

    
848
--
849
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
850
--
851

    
852
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
853
REVOKE ALL ON TABLE taxon_scrub FROM bien;
854
GRANT ALL ON TABLE taxon_scrub TO bien;
855
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
856

    
857

    
858
--
859
-- PostgreSQL database dump complete
860
--
861

    
(8-8/10)