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

    
39

    
40
SET search_path = "TNRS", pg_catalog;
41

    
42
--
43
-- Name: MatchedTaxon_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
44
--
45

    
46
CREATE FUNCTION "MatchedTaxon_modify"(view_query text) RETURNS void
47
    LANGUAGE sql
48
    AS $_$
49
SELECT util.force_recreate($$
50
-- trigger the dependent_objects_still_exist exception
51
DROP VIEW "TNRS"."MatchedTaxon"; -- *not* CASCADE; it must trigger an exception
52

    
53
CREATE VIEW "TNRS"."MatchedTaxon" AS 
54
$$||$1||$$
55
;
56
$$||util.mk_set_relation_metadata('"TNRS"."MatchedTaxon"')||$$
57

    
58
-- manually restore views that need to be updated for the changes
59
-- **IMPORTANT**: keep these updated as described in the views' comments
60

    
61
CREATE VIEW "TNRS"."ValidMatchedTaxon" AS 
62
 SELECT *
63
   FROM "TNRS"."MatchedTaxon"
64
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
65
$$||util.mk_set_relation_metadata('"TNRS"."ValidMatchedTaxon"')||$$
66

    
67
CREATE VIEW "TNRS".taxon_scrub AS 
68
 SELECT *
69
   FROM "TNRS"."ValidMatchedTaxon"
70
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
71
$$||util.mk_set_relation_metadata('"TNRS".taxon_scrub')||$$
72
$$);
73
$_$;
74

    
75

    
76
--
77
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
78
--
79

    
80
CREATE FUNCTION batch__fill() RETURNS trigger
81
    LANGUAGE plpgsql
82
    AS $$
83
BEGIN
84
	new.id_by_time = new.time_submitted;
85
	new.id = COALESCE(new.id, new.id_by_time);
86
	RETURN new;
87
END;
88
$$;
89

    
90

    
91
--
92
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
93
--
94

    
95
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
96
    LANGUAGE sql STABLE STRICT
97
    AS $_$
98
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
99
$_$;
100

    
101

    
102
--
103
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
104
--
105

    
106
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
107
    LANGUAGE sql STABLE STRICT
108
    AS $_$
109
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
110
$_$;
111

    
112

    
113
--
114
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
115
--
116

    
117
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
118
    LANGUAGE sql IMMUTABLE
119
    AS $_$
120
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
121
"taxonomic_status should be accepted instead of synonym when an accepted name is
122
available (this is not always the case when a name is marked as a synonym)" */
123
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
124
$_$;
125

    
126

    
127
--
128
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
129
--
130

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

    
188

    
189
--
190
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
191
--
192

    
193
COMMENT ON FUNCTION tnrs_populate_fields() IS 'IMPORTANT: when changing this function, you must regenerate the derived cols:
194
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
195
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
196
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
197
runtime: 1.5 min ("92633 ms")';
198

    
199

    
200
SET default_tablespace = '';
201

    
202
SET default_with_oids = false;
203

    
204
--
205
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
206
--
207

    
208
CREATE TABLE tnrs (
209
    batch text DEFAULT now() NOT NULL,
210
    "Name_number" integer NOT NULL,
211
    "Name_submitted" text NOT NULL,
212
    "Overall_score" double precision,
213
    "Name_matched" text,
214
    "Name_matched_rank" text,
215
    "Name_score" double precision,
216
    "Name_matched_author" text,
217
    "Name_matched_url" text,
218
    "Author_matched" text,
219
    "Author_score" double precision,
220
    "Family_matched" text,
221
    "Family_score" double precision,
222
    "Name_matched_accepted_family" text,
223
    "Genus_matched" text,
224
    "Genus_score" double precision,
225
    "Specific_epithet_matched" text,
226
    "Specific_epithet_score" double precision,
227
    "Infraspecific_rank" text,
228
    "Infraspecific_epithet_matched" text,
229
    "Infraspecific_epithet_score" double precision,
230
    "Infraspecific_rank_2" text,
231
    "Infraspecific_epithet_2_matched" text,
232
    "Infraspecific_epithet_2_score" double precision,
233
    "Annotations" text,
234
    "Unmatched_terms" text,
235
    "Taxonomic_status" text,
236
    "Accepted_name" text,
237
    "Accepted_name_author" text,
238
    "Accepted_name_rank" text,
239
    "Accepted_name_url" text,
240
    "Accepted_name_species" text,
241
    "Accepted_name_family" text,
242
    "Selected" text,
243
    "Source" text,
244
    "Warnings" text,
245
    "Accepted_name_lsid" text,
246
    is_valid_match boolean NOT NULL,
247
    scrubbed_unique_taxon_name text
248
);
249

    
250

    
251
--
252
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
253
--
254

    
255
COMMENT ON TABLE tnrs IS 'IMPORTANT: when changing this table''s schema, you may need to re-run TNRS:
256
$ inputs/.TNRS/data.sql.run refresh';
257

    
258

    
259
--
260
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
261
--
262

    
263
CREATE VIEW "MatchedTaxon" AS
264
 SELECT s."*Name_matched.batch", 
265
    s."concatenatedScientificName", 
266
    s."matchedTaxonName", 
267
    s."matchedTaxonRank", 
268
    s."*Name_matched.Name_score", 
269
    s."matchedScientificNameAuthorship", 
270
    s."matchedScientificNameID", 
271
    s."*Name_matched.Author_score", 
272
    s."matchedFamilyConfidence_fraction", 
273
    s."matchedFamily", 
274
    s."matchedGenus", 
275
    s."matchedGenusConfidence_fraction", 
276
    s."matchedSpecificEpithet", 
277
    s."matchedSpeciesConfidence_fraction", 
278
    s."matchedInfraspecificEpithet", 
279
    s."*Name_matched.Infraspecific_epithet_score", 
280
    s."identificationQualifier", 
281
    s."morphospeciesSuffix", 
282
    s."taxonomicStatus", 
283
    s.accepted_taxon_name_no_author, 
284
    s.accepted_author, 
285
    s.accepted_taxon_rank, 
286
    s."acceptedScientificNameID", 
287
    s.accepted_species_binomial, 
288
    s.accepted_family, 
289
    s."*Name_matched.Selected", 
290
    s."*Name_matched.Source", 
291
    s."*Name_matched.Warnings", 
292
    s."*Name_matched.Accepted_name_lsid", 
293
    s.taxon_scrub__is_valid_match, 
294
    s.scrubbed_unique_taxon_name, 
295
        CASE
296
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
297
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
298
            ELSE s.accepted_species_binomial
299
        END AS accepted_morphospecies_binomial
300
   FROM ( SELECT tnrs.batch AS "*Name_matched.batch", 
301
            tnrs."Name_submitted" AS "concatenatedScientificName", 
302
            tnrs."Name_matched" AS "matchedTaxonName", 
303
            tnrs."Name_matched_rank" AS "matchedTaxonRank", 
304
            tnrs."Name_score" AS "*Name_matched.Name_score", 
305
            tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", 
306
            tnrs."Name_matched_url" AS "matchedScientificNameID", 
307
            tnrs."Author_score" AS "*Name_matched.Author_score", 
308
            tnrs."Family_score" AS "matchedFamilyConfidence_fraction", 
309
            COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", 
310
            tnrs."Genus_matched" AS "matchedGenus", 
311
            tnrs."Genus_score" AS "matchedGenusConfidence_fraction", 
312
            tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", 
313
            tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", 
314
            tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", 
315
            tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", 
316
            tnrs."Annotations" AS "identificationQualifier", 
317
            tnrs."Unmatched_terms" AS "morphospeciesSuffix", 
318
            tnrs."Taxonomic_status" AS "taxonomicStatus", 
319
            tnrs."Accepted_name" AS accepted_taxon_name_no_author, 
320
            tnrs."Accepted_name_author" AS accepted_author, 
321
            tnrs."Accepted_name_rank" AS accepted_taxon_rank, 
322
            tnrs."Accepted_name_url" AS "acceptedScientificNameID", 
323
            tnrs."Accepted_name_species" AS accepted_species_binomial, 
324
            tnrs."Accepted_name_family" AS accepted_family, 
325
            tnrs."Selected" AS "*Name_matched.Selected", 
326
            tnrs."Source" AS "*Name_matched.Source", 
327
            tnrs."Warnings" AS "*Name_matched.Warnings", 
328
            tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", 
329
            tnrs.is_valid_match AS taxon_scrub__is_valid_match, 
330
            tnrs.scrubbed_unique_taxon_name
331
           FROM tnrs) s;
332

    
333

    
334
--
335
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
336
--
337

    
338
COMMENT ON VIEW "MatchedTaxon" IS '
339
to modify:
340
-- use `*, ... AS accepted_morphospecies_binomial` as the column list
341
SELECT util.force_recreate($$
342
-- trigger the dependent_objects_still_exist exception
343
DROP VIEW "TNRS"."MatchedTaxon"; -- *not* CASCADE; it must trigger an exception
344

    
345
CREATE VIEW "TNRS"."MatchedTaxon" AS 
346
SELECT *, ... AS accepted_morphospecies_binomial
347
/*revised def*/
348
;
349
GRANT SELECT ON TABLE "TNRS"."MatchedTaxon" TO bien_read;
350
COMMENT ON VIEW "TNRS"."MatchedTaxon"
351
  IS ''
352
...
353
'';
354

    
355
-- manually restore views that need to be updated for the changes
356
-- **IMPORTANT**: update these as described in the views'' comments
357

    
358
CREATE VIEW "TNRS"."ValidMatchedTaxon" AS 
359
 SELECT *
360
   FROM "TNRS"."MatchedTaxon"
361
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
362
GRANT SELECT ON TABLE "TNRS"."ValidMatchedTaxon" TO bien_read;
363
COMMENT ON VIEW "TNRS"."ValidMatchedTaxon"
364
  IS ''
365
to update, use * as the column list
366
'';
367

    
368
CREATE VIEW "TNRS".taxon_scrub AS 
369
 SELECT *
370
   FROM "TNRS"."ValidMatchedTaxon"
371
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
372
GRANT SELECT ON TABLE "TNRS".taxon_scrub TO bien_read;
373
COMMENT ON VIEW "TNRS".taxon_scrub
374
  IS ''
375
to update, use * as the column list
376
'';
377
$$);
378
';
379

    
380

    
381
--
382
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
383
--
384

    
385
CREATE VIEW "ValidMatchedTaxon" AS
386
 SELECT "MatchedTaxon"."*Name_matched.batch", 
387
    "MatchedTaxon"."concatenatedScientificName", 
388
    "MatchedTaxon"."matchedTaxonName", 
389
    "MatchedTaxon"."matchedTaxonRank", 
390
    "MatchedTaxon"."*Name_matched.Name_score", 
391
    "MatchedTaxon"."matchedScientificNameAuthorship", 
392
    "MatchedTaxon"."matchedScientificNameID", 
393
    "MatchedTaxon"."*Name_matched.Author_score", 
394
    "MatchedTaxon"."matchedFamilyConfidence_fraction", 
395
    "MatchedTaxon"."matchedFamily", 
396
    "MatchedTaxon"."matchedGenus", 
397
    "MatchedTaxon"."matchedGenusConfidence_fraction", 
398
    "MatchedTaxon"."matchedSpecificEpithet", 
399
    "MatchedTaxon"."matchedSpeciesConfidence_fraction", 
400
    "MatchedTaxon"."matchedInfraspecificEpithet", 
401
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
402
    "MatchedTaxon"."identificationQualifier", 
403
    "MatchedTaxon"."morphospeciesSuffix", 
404
    "MatchedTaxon"."taxonomicStatus", 
405
    "MatchedTaxon".accepted_taxon_name_no_author, 
406
    "MatchedTaxon".accepted_author, 
407
    "MatchedTaxon".accepted_taxon_rank, 
408
    "MatchedTaxon"."acceptedScientificNameID", 
409
    "MatchedTaxon".accepted_species_binomial, 
410
    "MatchedTaxon".accepted_family, 
411
    "MatchedTaxon"."*Name_matched.Selected", 
412
    "MatchedTaxon"."*Name_matched.Source", 
413
    "MatchedTaxon"."*Name_matched.Warnings", 
414
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid", 
415
    "MatchedTaxon".taxon_scrub__is_valid_match, 
416
    "MatchedTaxon".scrubbed_unique_taxon_name, 
417
    "MatchedTaxon".accepted_morphospecies_binomial
418
   FROM "MatchedTaxon"
419
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
420

    
421

    
422
--
423
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
424
--
425

    
426
COMMENT ON VIEW "ValidMatchedTaxon" IS '
427
to update, use * as the column list
428
';
429

    
430

    
431
--
432
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
433
--
434

    
435
CREATE TABLE batch (
436
    id text NOT NULL,
437
    id_by_time text,
438
    time_submitted timestamp with time zone DEFAULT now(),
439
    client_version text
440
);
441

    
442

    
443
--
444
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
445
--
446

    
447
CREATE TABLE batch_download_settings (
448
    id text NOT NULL,
449
    "E-mail" text,
450
    "Id" text,
451
    "Job type" text,
452
    "Contains Id" boolean,
453
    "Start time" text,
454
    "Finish time" text,
455
    "TNRS version" text,
456
    "Sources selected" text,
457
    "Match threshold" double precision,
458
    "Classification" text,
459
    "Allow partial matches?" boolean,
460
    "Sort by source" boolean,
461
    "Constrain by higher taxonomy" boolean
462
);
463

    
464

    
465
--
466
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
467
--
468

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

    
471

    
472
--
473
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
474
--
475

    
476
CREATE TABLE client_version (
477
    id text NOT NULL,
478
    global_rev integer NOT NULL,
479
    "/lib/tnrs.py rev" integer,
480
    "/bin/tnrs_db rev" integer
481
);
482

    
483

    
484
--
485
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
486
--
487

    
488
COMMENT ON TABLE client_version IS 'contains svn revisions';
489

    
490

    
491
--
492
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
493
--
494

    
495
COMMENT ON COLUMN client_version.global_rev IS 'from `svn info .` > Last Changed Rev';
496

    
497

    
498
--
499
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
500
--
501

    
502
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS 'from `svn info lib/tnrs.py` > Last Changed Rev';
503

    
504

    
505
--
506
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
507
--
508

    
509
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS 'from `svn info bin/tnrs_db` > Last Changed Rev';
510

    
511

    
512
--
513
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
514
--
515

    
516
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
517
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
518
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
519
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
520
    tnrs."Genus_matched" AS scrubbed_genus, 
521
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
522
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
523
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
524
    tnrs."Name_matched_author" AS scrubbed_author, 
525
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author
526
   FROM tnrs;
527

    
528

    
529
--
530
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
531
--
532

    
533
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '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.';
534

    
535

    
536
--
537
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
538
--
539

    
540
CREATE VIEW taxon_scrub AS
541
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
542
    "ValidMatchedTaxon"."*Name_matched.batch", 
543
    "ValidMatchedTaxon"."concatenatedScientificName", 
544
    "ValidMatchedTaxon"."matchedTaxonName", 
545
    "ValidMatchedTaxon"."matchedTaxonRank", 
546
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
547
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
548
    "ValidMatchedTaxon"."matchedScientificNameID", 
549
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
550
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
551
    "ValidMatchedTaxon"."matchedFamily", 
552
    "ValidMatchedTaxon"."matchedGenus", 
553
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
554
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
555
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
556
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
557
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
558
    "ValidMatchedTaxon"."identificationQualifier", 
559
    "ValidMatchedTaxon"."morphospeciesSuffix", 
560
    "ValidMatchedTaxon"."taxonomicStatus", 
561
    "ValidMatchedTaxon".accepted_taxon_name_no_author, 
562
    "ValidMatchedTaxon".accepted_author, 
563
    "ValidMatchedTaxon".accepted_taxon_rank, 
564
    "ValidMatchedTaxon"."acceptedScientificNameID", 
565
    "ValidMatchedTaxon".accepted_species_binomial, 
566
    "ValidMatchedTaxon".accepted_family, 
567
    "ValidMatchedTaxon"."*Name_matched.Selected", 
568
    "ValidMatchedTaxon"."*Name_matched.Source", 
569
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
570
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
571
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
572
    "ValidMatchedTaxon".accepted_morphospecies_binomial, 
573
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
574
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
575
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
576
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
577
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
578
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
579
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
580
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author
581
   FROM ("ValidMatchedTaxon"
582
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
583

    
584

    
585
--
586
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
587
--
588

    
589
COMMENT ON VIEW taxon_scrub IS '
590
to update, use * as the column list
591
';
592

    
593

    
594
--
595
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
596
--
597

    
598
ALTER TABLE ONLY batch_download_settings
599
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
600

    
601

    
602
--
603
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
604
--
605

    
606
ALTER TABLE ONLY batch
607
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
608

    
609

    
610
--
611
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
612
--
613

    
614
ALTER TABLE ONLY batch
615
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
616

    
617

    
618
--
619
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
620
--
621

    
622
ALTER TABLE ONLY client_version
623
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
624

    
625

    
626
--
627
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
628
--
629

    
630
ALTER TABLE ONLY tnrs
631
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
632

    
633

    
634
--
635
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
636
--
637

    
638
ALTER TABLE ONLY tnrs
639
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
640

    
641

    
642
--
643
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
644
--
645

    
646
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
647

    
648

    
649
--
650
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
651
--
652

    
653
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
654

    
655

    
656
--
657
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
658
--
659

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

    
662

    
663
--
664
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
665
--
666

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

    
669

    
670
--
671
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
672
--
673

    
674
ALTER TABLE ONLY batch
675
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
676

    
677

    
678
--
679
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
680
--
681

    
682
ALTER TABLE ONLY batch_download_settings
683
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
684

    
685

    
686
--
687
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
688
--
689

    
690
ALTER TABLE ONLY tnrs
691
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
692

    
693

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

    
698
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
699
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
700
GRANT ALL ON SCHEMA "TNRS" TO bien;
701
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
702

    
703

    
704
--
705
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
706
--
707

    
708
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
709
REVOKE ALL ON TABLE tnrs FROM bien;
710
GRANT ALL ON TABLE tnrs TO bien;
711
GRANT SELECT ON TABLE tnrs TO bien_read;
712

    
713

    
714
--
715
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
716
--
717

    
718
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
719
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
720
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
721
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
722

    
723

    
724
--
725
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
726
--
727

    
728
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
729
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
730
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
731
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
732

    
733

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

    
738
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
739
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
740
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
741
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
742

    
743

    
744
--
745
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
746
--
747

    
748
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
749
REVOKE ALL ON TABLE taxon_scrub FROM bien;
750
GRANT ALL ON TABLE taxon_scrub TO bien;
751
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
752

    
753

    
754
--
755
-- PostgreSQL database dump complete
756
--
757

    
(8-8/10)