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: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
44
--
45

    
46
CREATE FUNCTION batch__fill() RETURNS trigger
47
    LANGUAGE plpgsql
48
    AS $$
49
BEGIN
50
	new.id_by_time = new.time_submitted;
51
	new.id = COALESCE(new.id, new.id_by_time);
52
	RETURN new;
53
END;
54
$$;
55

    
56

    
57
--
58
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
59
--
60

    
61
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
62
    LANGUAGE sql STABLE STRICT
63
    AS $_$
64
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
65
$_$;
66

    
67

    
68
--
69
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
70
--
71

    
72
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
73
    LANGUAGE sql STABLE STRICT
74
    AS $_$
75
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
76
$_$;
77

    
78

    
79
--
80
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
81
--
82

    
83
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, scrubbed_unique_taxon_name text) RETURNS text
84
    LANGUAGE sql IMMUTABLE
85
    AS $_$
86
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
87
$_$;
88

    
89

    
90
--
91
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
92
--
93

    
94
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
95
    LANGUAGE plpgsql
96
    AS $$
97
DECLARE
98
	"Specific_epithet_is_plant" boolean :=
99
		(CASE
100
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
101
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
102
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
103
			THEN true
104
		ELSE NULL -- ambiguous
105
		END);
106
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
107
		-- author disambiguates
108
	family_is_homonym boolean = NOT never_homonym
109
		AND "TNRS".family_is_homonym(new."Family_matched");
110
	genus_is_homonym  boolean = NOT never_homonym
111
		AND "TNRS".genus_is_homonym(new."Genus_matched");
112
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
113
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
114
			new."Name_matched")
115
		, NULLIF(new."Name_matched", 'No suitable matches found.')
116
		, new."Name_matched_author"
117
		), '');
118
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
119
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
120
			new."Accepted_name")
121
		, new."Accepted_name"
122
		, new."Accepted_name_author"
123
		), '');
124
BEGIN
125
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
126
	a name, but the name is not meaningful because it is not unambiguous). */
127
	new.is_valid_match = new."Taxonomic_status" != 'Invalid'
128
		AND COALESCE(CASE
129
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
130
			THEN true
131
		ELSE -- consider genus
132
			(CASE
133
			WHEN new."Genus_score" =  1	   -- exact match
134
				THEN
135
				(CASE
136
				WHEN NOT genus_is_homonym THEN true
137
				ELSE "Specific_epithet_is_plant"
138
				END)
139
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
140
				THEN "Specific_epithet_is_plant"
141
			ELSE NULL -- ambiguous
142
			END)
143
		END, false);
144
	new.scrubbed_unique_taxon_name = COALESCE(
145
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
146
	
147
	RETURN new;
148
END;
149
$$;
150

    
151

    
152
--
153
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
154
--
155

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

    
162

    
163
SET default_tablespace = '';
164

    
165
SET default_with_oids = false;
166

    
167
--
168
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
169
--
170

    
171
CREATE TABLE tnrs (
172
    batch text DEFAULT now() NOT NULL,
173
    "Name_number" integer NOT NULL,
174
    "Name_submitted" text NOT NULL,
175
    "Overall_score" double precision,
176
    "Name_matched" text,
177
    "Name_matched_rank" text,
178
    "Name_score" double precision,
179
    "Name_matched_author" text,
180
    "Name_matched_url" text,
181
    "Author_matched" text,
182
    "Author_score" double precision,
183
    "Family_matched" text,
184
    "Family_score" double precision,
185
    "Name_matched_accepted_family" text,
186
    "Genus_matched" text,
187
    "Genus_score" double precision,
188
    "Specific_epithet_matched" text,
189
    "Specific_epithet_score" double precision,
190
    "Infraspecific_rank" text,
191
    "Infraspecific_epithet_matched" text,
192
    "Infraspecific_epithet_score" double precision,
193
    "Infraspecific_rank_2" text,
194
    "Infraspecific_epithet_2_matched" text,
195
    "Infraspecific_epithet_2_score" double precision,
196
    "Annotations" text,
197
    "Unmatched_terms" text,
198
    "Taxonomic_status" text,
199
    "Accepted_name" text,
200
    "Accepted_name_author" text,
201
    "Accepted_name_rank" text,
202
    "Accepted_name_url" text,
203
    "Accepted_name_species" text,
204
    "Accepted_name_family" text,
205
    "Selected" text,
206
    "Source" text,
207
    "Warnings" text,
208
    "Accepted_name_lsid" text,
209
    is_valid_match boolean NOT NULL,
210
    scrubbed_unique_taxon_name text
211
);
212

    
213

    
214
--
215
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
216
--
217

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

    
221

    
222
--
223
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
224
--
225

    
226
CREATE VIEW "MatchedTaxon" AS
227
 SELECT tnrs.batch AS "*Name_matched.batch", 
228
    tnrs."Name_submitted" AS "concatenatedScientificName", 
229
    tnrs."Name_matched" AS "matchedTaxonName", 
230
    tnrs."Name_matched_rank" AS "matchedTaxonRank", 
231
    tnrs."Name_score" AS "*Name_matched.Name_score", 
232
    tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", 
233
    tnrs."Name_matched_url" AS "matchedScientificNameID", 
234
    tnrs."Author_score" AS "*Name_matched.Author_score", 
235
    tnrs."Family_score" AS "matchedFamilyConfidence_fraction", 
236
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", 
237
    tnrs."Genus_matched" AS "matchedGenus", 
238
    tnrs."Genus_score" AS "matchedGenusConfidence_fraction", 
239
    tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", 
240
    tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", 
241
    tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", 
242
    tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", 
243
    tnrs."Annotations" AS "identificationQualifier", 
244
    tnrs."Unmatched_terms" AS "morphospeciesSuffix", 
245
    tnrs."Taxonomic_status" AS "taxonomicStatus", 
246
    tnrs."Accepted_name" AS accepted_taxon_name_no_author, 
247
    tnrs."Accepted_name_author" AS accepted_author, 
248
    tnrs."Accepted_name_rank" AS accepted_taxon_rank, 
249
    tnrs."Accepted_name_url" AS "acceptedScientificNameID", 
250
    tnrs."Accepted_name_species" AS accepted_species_binomial, 
251
    tnrs."Accepted_name_family" AS accepted_family, 
252
    tnrs."Selected" AS "*Name_matched.Selected", 
253
    tnrs."Source" AS "*Name_matched.Source", 
254
    tnrs."Warnings" AS "*Name_matched.Warnings", 
255
    tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", 
256
    tnrs.is_valid_match AS taxon_scrub__is_valid_match, 
257
    tnrs.scrubbed_unique_taxon_name
258
   FROM tnrs;
259

    
260

    
261
--
262
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
263
--
264

    
265
CREATE VIEW "ValidMatchedTaxon" AS
266
 SELECT "MatchedTaxon"."*Name_matched.batch", 
267
    "MatchedTaxon"."concatenatedScientificName", 
268
    "MatchedTaxon"."matchedTaxonName", 
269
    "MatchedTaxon"."matchedTaxonRank", 
270
    "MatchedTaxon"."*Name_matched.Name_score", 
271
    "MatchedTaxon"."matchedScientificNameAuthorship", 
272
    "MatchedTaxon"."matchedScientificNameID", 
273
    "MatchedTaxon"."*Name_matched.Author_score", 
274
    "MatchedTaxon"."matchedFamilyConfidence_fraction", 
275
    "MatchedTaxon"."matchedFamily", 
276
    "MatchedTaxon"."matchedGenus", 
277
    "MatchedTaxon"."matchedGenusConfidence_fraction", 
278
    "MatchedTaxon"."matchedSpecificEpithet", 
279
    "MatchedTaxon"."matchedSpeciesConfidence_fraction", 
280
    "MatchedTaxon"."matchedInfraspecificEpithet", 
281
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
282
    "MatchedTaxon"."identificationQualifier", 
283
    "MatchedTaxon"."morphospeciesSuffix", 
284
    "MatchedTaxon"."taxonomicStatus", 
285
    "MatchedTaxon".accepted_taxon_name_no_author, 
286
    "MatchedTaxon".accepted_author, 
287
    "MatchedTaxon".accepted_taxon_rank, 
288
    "MatchedTaxon"."acceptedScientificNameID", 
289
    "MatchedTaxon".accepted_species_binomial, 
290
    "MatchedTaxon".accepted_family, 
291
    "MatchedTaxon"."*Name_matched.Selected", 
292
    "MatchedTaxon"."*Name_matched.Source", 
293
    "MatchedTaxon"."*Name_matched.Warnings", 
294
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid", 
295
    "MatchedTaxon".taxon_scrub__is_valid_match, 
296
    "MatchedTaxon".scrubbed_unique_taxon_name
297
   FROM "MatchedTaxon"
298
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
299

    
300

    
301
--
302
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
303
--
304

    
305
COMMENT ON VIEW "ValidMatchedTaxon" IS '
306
to update, use * as the column list
307
';
308

    
309

    
310
--
311
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
312
--
313

    
314
CREATE TABLE batch (
315
    id text NOT NULL,
316
    id_by_time text,
317
    time_submitted timestamp with time zone DEFAULT now(),
318
    client_version text
319
);
320

    
321

    
322
--
323
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
324
--
325

    
326
CREATE TABLE batch_download_settings (
327
    id text NOT NULL,
328
    "E-mail" text,
329
    "Id" text,
330
    "Job type" text,
331
    "Contains Id" boolean,
332
    "Start time" text,
333
    "Finish time" text,
334
    "TNRS version" text,
335
    "Sources selected" text,
336
    "Match threshold" double precision,
337
    "Classification" text,
338
    "Allow partial matches?" boolean,
339
    "Sort by source" boolean,
340
    "Constrain by higher taxonomy" boolean
341
);
342

    
343

    
344
--
345
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
346
--
347

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

    
350

    
351
--
352
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
353
--
354

    
355
CREATE TABLE client_version (
356
    id text NOT NULL,
357
    global_rev integer NOT NULL,
358
    "/lib/tnrs.py rev" integer,
359
    "/bin/tnrs_db rev" integer
360
);
361

    
362

    
363
--
364
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
365
--
366

    
367
COMMENT ON TABLE client_version IS 'contains svn revisions';
368

    
369

    
370
--
371
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
372
--
373

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

    
376

    
377
--
378
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
379
--
380

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

    
383

    
384
--
385
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
386
--
387

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

    
390

    
391
--
392
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
393
--
394

    
395
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
396
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
397
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
398
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
399
    tnrs."Genus_matched" AS scrubbed_genus, 
400
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
401
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
402
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
403
    tnrs."Name_matched_author" AS scrubbed_author, 
404
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author
405
   FROM tnrs;
406

    
407

    
408
--
409
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
410
--
411

    
412
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.';
413

    
414

    
415
--
416
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
417
--
418

    
419
CREATE VIEW taxon_scrub AS
420
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
421
    "ValidMatchedTaxon"."*Name_matched.batch", 
422
    "ValidMatchedTaxon"."concatenatedScientificName", 
423
    "ValidMatchedTaxon"."matchedTaxonName", 
424
    "ValidMatchedTaxon"."matchedTaxonRank", 
425
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
426
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
427
    "ValidMatchedTaxon"."matchedScientificNameID", 
428
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
429
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
430
    "ValidMatchedTaxon"."matchedFamily", 
431
    "ValidMatchedTaxon"."matchedGenus", 
432
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
433
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
434
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
435
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
436
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
437
    "ValidMatchedTaxon"."identificationQualifier", 
438
    "ValidMatchedTaxon"."morphospeciesSuffix", 
439
    "ValidMatchedTaxon"."taxonomicStatus", 
440
    "ValidMatchedTaxon".accepted_taxon_name_no_author, 
441
    "ValidMatchedTaxon".accepted_author, 
442
    "ValidMatchedTaxon".accepted_taxon_rank, 
443
    "ValidMatchedTaxon"."acceptedScientificNameID", 
444
    "ValidMatchedTaxon".accepted_species_binomial, 
445
    "ValidMatchedTaxon".accepted_family, 
446
    "ValidMatchedTaxon"."*Name_matched.Selected", 
447
    "ValidMatchedTaxon"."*Name_matched.Source", 
448
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
449
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
450
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
451
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
452
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
453
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
454
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
455
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
456
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
457
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
458
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author
459
   FROM ("ValidMatchedTaxon"
460
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
461

    
462

    
463
--
464
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
465
--
466

    
467
COMMENT ON VIEW taxon_scrub IS '
468
to update, use * as the column list
469
';
470

    
471

    
472
--
473
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
474
--
475

    
476
ALTER TABLE ONLY batch_download_settings
477
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
478

    
479

    
480
--
481
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
482
--
483

    
484
ALTER TABLE ONLY batch
485
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
486

    
487

    
488
--
489
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
490
--
491

    
492
ALTER TABLE ONLY batch
493
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
494

    
495

    
496
--
497
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
498
--
499

    
500
ALTER TABLE ONLY client_version
501
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
502

    
503

    
504
--
505
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
506
--
507

    
508
ALTER TABLE ONLY tnrs
509
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
510

    
511

    
512
--
513
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
514
--
515

    
516
ALTER TABLE ONLY tnrs
517
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
518

    
519

    
520
--
521
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
522
--
523

    
524
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
525

    
526

    
527
--
528
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
529
--
530

    
531
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
532

    
533

    
534
--
535
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
536
--
537

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

    
540

    
541
--
542
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
543
--
544

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

    
547

    
548
--
549
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
550
--
551

    
552
ALTER TABLE ONLY batch
553
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
554

    
555

    
556
--
557
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
558
--
559

    
560
ALTER TABLE ONLY batch_download_settings
561
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
562

    
563

    
564
--
565
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
566
--
567

    
568
ALTER TABLE ONLY tnrs
569
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
570

    
571

    
572
--
573
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
574
--
575

    
576
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
577
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
578
GRANT ALL ON SCHEMA "TNRS" TO bien;
579
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
580

    
581

    
582
--
583
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
584
--
585

    
586
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
587
REVOKE ALL ON TABLE tnrs FROM bien;
588
GRANT ALL ON TABLE tnrs TO bien;
589
GRANT SELECT ON TABLE tnrs TO bien_read;
590

    
591

    
592
--
593
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
594
--
595

    
596
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
597
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
598
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
599
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
600

    
601

    
602
--
603
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
604
--
605

    
606
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
607
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
608
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
609
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
610

    
611

    
612
--
613
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
614
--
615

    
616
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
617
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
618
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
619
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
620

    
621

    
622
--
623
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
624
--
625

    
626
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
627
REVOKE ALL ON TABLE taxon_scrub FROM bien;
628
GRANT ALL ON TABLE taxon_scrub TO bien;
629
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
630

    
631

    
632
--
633
-- PostgreSQL database dump complete
634
--
635

    
(8-8/10)