Project

General

Profile

1
--
2
-- PostgreSQL database dump
3
--
4

    
5
SET statement_timeout = 0;
6
SET client_encoding = 'UTF8';
7
SET standard_conforming_strings = on;
8
SET check_function_bodies = false;
9
SET client_min_messages = warning;
10

    
11
--
12
-- Name: TNRS; Type: SCHEMA; Schema: -; Owner: -
13
--
14

    
15
--CREATE SCHEMA "TNRS";
16

    
17

    
18
--
19
-- Name: SCHEMA "TNRS"; Type: COMMENT; Schema: -; Owner: -
20
--
21

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

    
38

    
39
SET search_path = "TNRS", pg_catalog;
40

    
41
--
42
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
43
--
44

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

    
55

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

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

    
66

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

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

    
77

    
78
--
79
-- Name: score_ok(double precision); Type: FUNCTION; Schema: TNRS; Owner: -
80
--
81

    
82
CREATE FUNCTION score_ok(score double precision) RETURNS boolean
83
    LANGUAGE sql IMMUTABLE
84
    AS $_$
85
SELECT $1 >= 0.8
86
$_$;
87

    
88

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

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

    
147

    
148
--
149
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
150
--
151

    
152
COMMENT ON FUNCTION tnrs_populate_fields() IS 'IMPORTANT: when changing this function, you must regenerate the derived cols:
153
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
154
runtime: 25 min ("5363526 rows affected, 1351907 ms execution time")
155
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
156
runtime: 1.5 min ("92633 ms")';
157

    
158

    
159
SET default_tablespace = '';
160

    
161
SET default_with_oids = false;
162

    
163
--
164
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
165
--
166

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

    
212

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

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

    
220

    
221
--
222
-- Name: AcceptedTaxon; Type: VIEW; Schema: TNRS; Owner: -
223
--
224

    
225
CREATE VIEW "AcceptedTaxon" AS
226
    SELECT tnrs.batch AS "*Accepted_name.batch", tnrs."Name_submitted" AS "acceptedScientificName", tnrs."Genus_matched" AS "acceptedGenus", tnrs."Specific_epithet_matched" AS "acceptedSpecificEpithet", tnrs."Infraspecific_epithet_matched" AS "acceptedInfraspecificEpithet", tnrs."Taxonomic_status" AS "acceptedTaxonomicStatus", tnrs."Selected" AS "*Accepted_name.Selected", tnrs."Source" AS "*Accepted_name.Source", tnrs."Warnings" AS "*Accepted_name.Warnings", tnrs."Accepted_name_lsid" AS "*Accepted_name.Accepted_name_lsid" FROM tnrs;
227

    
228

    
229
--
230
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
231
--
232

    
233
CREATE VIEW "MatchedTaxon" AS
234
    SELECT tnrs.batch AS "*Name_matched.batch", tnrs."Name_submitted" AS "concatenatedScientificName", tnrs."Name_matched" AS "matchedTaxonName", tnrs."Name_matched_rank" AS "matchedTaxonRank", tnrs."Name_score" AS "*Name_matched.Name_score", tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", tnrs."Name_matched_url" AS "matchedScientificNameID", tnrs."Author_score" AS "*Name_matched.Author_score", tnrs."Family_score" AS "matchedFamilyConfidence_fraction", COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", tnrs."Genus_matched" AS "matchedGenus", tnrs."Genus_score" AS "matchedGenusConfidence_fraction", tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", tnrs."Annotations" AS "identificationQualifier", tnrs."Unmatched_terms" AS "morphospeciesSuffix", tnrs."Taxonomic_status" AS "taxonomicStatus", tnrs."Accepted_name" AS "acceptedTaxonName", tnrs."Accepted_name_author" AS "acceptedScientificNameAuthorship", tnrs."Accepted_name_rank" AS "acceptedTaxonRank", tnrs."Accepted_name_url" AS "acceptedScientificNameID", tnrs."Accepted_name_species" AS "*Name_matched.Accepted_name_species", tnrs."Accepted_name_family" AS "acceptedFamily", tnrs."Selected" AS "*Name_matched.Selected", tnrs."Source" AS "*Name_matched.Source", tnrs."Warnings" AS "*Name_matched.Warnings", tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", tnrs."Accepted_scientific_name" AS "acceptedScientificName", tnrs."Max_score" AS "matchedTaxonConfidence_fraction", tnrs.is_valid_match AS taxon_scrub__is_valid_match FROM tnrs;
235

    
236

    
237
--
238
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
239
--
240

    
241
CREATE VIEW "ValidMatchedTaxon" AS
242
    SELECT "MatchedTaxon"."*Name_matched.batch", "MatchedTaxon"."concatenatedScientificName", "MatchedTaxon"."matchedTaxonName", "MatchedTaxon"."matchedTaxonRank", "MatchedTaxon"."*Name_matched.Name_score", "MatchedTaxon"."matchedScientificNameAuthorship", "MatchedTaxon"."matchedScientificNameID", "MatchedTaxon"."*Name_matched.Author_score", "MatchedTaxon"."matchedFamilyConfidence_fraction", "MatchedTaxon"."matchedFamily", "MatchedTaxon"."matchedGenus", "MatchedTaxon"."matchedGenusConfidence_fraction", "MatchedTaxon"."matchedSpecificEpithet", "MatchedTaxon"."matchedSpeciesConfidence_fraction", "MatchedTaxon"."matchedInfraspecificEpithet", "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", "MatchedTaxon"."identificationQualifier", "MatchedTaxon"."morphospeciesSuffix", "MatchedTaxon"."taxonomicStatus", "MatchedTaxon"."acceptedTaxonName", "MatchedTaxon"."acceptedScientificNameAuthorship", "MatchedTaxon"."acceptedTaxonRank", "MatchedTaxon"."acceptedScientificNameID", "MatchedTaxon"."*Name_matched.Accepted_name_species", "MatchedTaxon"."acceptedFamily", "MatchedTaxon"."*Name_matched.Selected", "MatchedTaxon"."*Name_matched.Source", "MatchedTaxon"."*Name_matched.Warnings", "MatchedTaxon"."*Name_matched.Accepted_name_lsid", "MatchedTaxon"."acceptedScientificName", "MatchedTaxon"."matchedTaxonConfidence_fraction", "MatchedTaxon".taxon_scrub__is_valid_match FROM "MatchedTaxon" WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
243

    
244

    
245
--
246
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
247
--
248

    
249
COMMENT ON VIEW "ValidMatchedTaxon" IS 'to update, use * as the column list';
250

    
251

    
252
--
253
-- Name: ScrubbedTaxon; Type: VIEW; Schema: TNRS; Owner: -
254
--
255

    
256
CREATE VIEW "ScrubbedTaxon" AS
257
    SELECT "ValidMatchedTaxon"."acceptedScientificName", "ValidMatchedTaxon"."*Name_matched.batch", "ValidMatchedTaxon"."concatenatedScientificName", "ValidMatchedTaxon"."matchedTaxonName", "ValidMatchedTaxon"."matchedTaxonRank", "ValidMatchedTaxon"."*Name_matched.Name_score", "ValidMatchedTaxon"."matchedScientificNameAuthorship", "ValidMatchedTaxon"."matchedScientificNameID", "ValidMatchedTaxon"."*Name_matched.Author_score", "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", "ValidMatchedTaxon"."matchedFamily", "ValidMatchedTaxon"."matchedGenus", "ValidMatchedTaxon"."matchedGenusConfidence_fraction", "ValidMatchedTaxon"."matchedSpecificEpithet", "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", "ValidMatchedTaxon"."matchedInfraspecificEpithet", "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", "ValidMatchedTaxon"."identificationQualifier", "ValidMatchedTaxon"."morphospeciesSuffix", "ValidMatchedTaxon"."taxonomicStatus", "ValidMatchedTaxon"."acceptedTaxonName", "ValidMatchedTaxon"."acceptedScientificNameAuthorship", "ValidMatchedTaxon"."acceptedTaxonRank", "ValidMatchedTaxon"."acceptedScientificNameID", "ValidMatchedTaxon"."*Name_matched.Accepted_name_species", "ValidMatchedTaxon"."acceptedFamily", "ValidMatchedTaxon"."*Name_matched.Selected", "ValidMatchedTaxon"."*Name_matched.Source", "ValidMatchedTaxon"."*Name_matched.Warnings", "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", "ValidMatchedTaxon"."matchedTaxonConfidence_fraction", "AcceptedTaxon"."*Accepted_name.batch", "AcceptedTaxon"."acceptedGenus", "AcceptedTaxon"."acceptedSpecificEpithet", "AcceptedTaxon"."acceptedInfraspecificEpithet", "AcceptedTaxon"."acceptedTaxonomicStatus", "AcceptedTaxon"."*Accepted_name.Selected", "AcceptedTaxon"."*Accepted_name.Source", "AcceptedTaxon"."*Accepted_name.Warnings", "AcceptedTaxon"."*Accepted_name.Accepted_name_lsid" FROM ("ValidMatchedTaxon" NATURAL LEFT JOIN "AcceptedTaxon");
258

    
259

    
260
--
261
-- Name: VIEW "ScrubbedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
262
--
263

    
264
COMMENT ON VIEW "ScrubbedTaxon" IS 'to update, use * as the column list';
265

    
266

    
267
--
268
-- Name: Source; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
269
--
270

    
271
CREATE TABLE "Source" (
272
    "*row_num" integer NOT NULL,
273
    "sourceType" text DEFAULT 'aggregator'::text NOT NULL,
274
    "datasetURL" text DEFAULT 'http://tnrs.iplantcollaborative.org/TNRSapp.html'::text NOT NULL
275
);
276

    
277

    
278
--
279
-- Name: COLUMN "Source"."sourceType"; Type: COMMENT; Schema: TNRS; Owner: -
280
--
281

    
282
COMMENT ON COLUMN "Source"."sourceType" IS 'constant';
283

    
284

    
285
--
286
-- Name: COLUMN "Source"."datasetURL"; Type: COMMENT; Schema: TNRS; Owner: -
287
--
288

    
289
COMMENT ON COLUMN "Source"."datasetURL" IS 'constant';
290

    
291

    
292
--
293
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
294
--
295

    
296
CREATE TABLE batch (
297
    id text NOT NULL,
298
    id_by_time text,
299
    time_submitted timestamp with time zone DEFAULT now(),
300
    client_version text
301
);
302

    
303

    
304
--
305
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
306
--
307

    
308
CREATE TABLE batch_download_settings (
309
    id text NOT NULL,
310
    "E-mail" text,
311
    "Id" text,
312
    "Job type" text,
313
    "Contains Id" boolean,
314
    "Start time" text,
315
    "Finish time" text,
316
    "TNRS version" text,
317
    "Sources selected" text,
318
    "Match threshold" double precision,
319
    "Classification" text,
320
    "Allow partial matches?" boolean,
321
    "Sort by source" boolean,
322
    "Constrain by higher taxonomy" boolean
323
);
324

    
325

    
326
--
327
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
328
--
329

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

    
332

    
333
--
334
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
335
--
336

    
337
CREATE TABLE client_version (
338
    id text NOT NULL,
339
    global_rev integer NOT NULL,
340
    "/lib/tnrs.py rev" integer,
341
    "/bin/tnrs_db rev" integer
342
);
343

    
344

    
345
--
346
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
347
--
348

    
349
COMMENT ON TABLE client_version IS 'contains svn revisions';
350

    
351

    
352
--
353
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
354
--
355

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

    
358

    
359
--
360
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
361
--
362

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

    
365

    
366
--
367
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
368
--
369

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

    
372

    
373
--
374
-- Name: ~Source.map; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
375
--
376

    
377
CREATE TABLE "~Source.map" (
378
    "from" text NOT NULL,
379
    "to" text,
380
    filter text,
381
    notes text
382
);
383

    
384

    
385
--
386
-- Name: Source_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
387
--
388

    
389
ALTER TABLE ONLY "Source"
390
    ADD CONSTRAINT "Source_pkey" PRIMARY KEY ("*row_num");
391

    
392

    
393
--
394
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
395
--
396

    
397
ALTER TABLE ONLY batch_download_settings
398
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
399

    
400

    
401
--
402
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
403
--
404

    
405
ALTER TABLE ONLY batch
406
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
407

    
408

    
409
--
410
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
411
--
412

    
413
ALTER TABLE ONLY batch
414
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
415

    
416

    
417
--
418
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
419
--
420

    
421
ALTER TABLE ONLY client_version
422
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
423

    
424

    
425
--
426
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
427
--
428

    
429
ALTER TABLE ONLY tnrs
430
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
431

    
432

    
433
--
434
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
435
--
436

    
437
ALTER TABLE ONLY tnrs
438
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
439

    
440

    
441
--
442
-- Name: ~Source.map_from_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
443
--
444

    
445
ALTER TABLE ONLY "~Source.map"
446
    ADD CONSTRAINT "~Source.map_from_key" UNIQUE ("from");
447

    
448

    
449
--
450
-- Name: ~Source.map_to_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
451
--
452

    
453
ALTER TABLE ONLY "~Source.map"
454
    ADD CONSTRAINT "~Source.map_to_key" UNIQUE ("to");
455

    
456

    
457
--
458
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
459
--
460

    
461
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
462

    
463

    
464
--
465
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
466
--
467

    
468
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
469

    
470

    
471
--
472
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
473
--
474

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

    
477

    
478
--
479
-- Name: map_filter_insert; Type: TRIGGER; Schema: TNRS; Owner: -
480
--
481

    
482
CREATE TRIGGER map_filter_insert BEFORE INSERT ON "~Source.map" FOR EACH ROW EXECUTE PROCEDURE util.map_filter_insert();
483

    
484
ALTER TABLE "~Source.map" DISABLE TRIGGER map_filter_insert;
485

    
486

    
487
--
488
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
489
--
490

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

    
493

    
494
--
495
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
496
--
497

    
498
ALTER TABLE ONLY batch
499
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
500

    
501

    
502
--
503
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
504
--
505

    
506
ALTER TABLE ONLY batch_download_settings
507
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
508

    
509

    
510
--
511
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
512
--
513

    
514
ALTER TABLE ONLY tnrs
515
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
516

    
517

    
518
--
519
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
520
--
521

    
522
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
523
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
524
GRANT ALL ON SCHEMA "TNRS" TO bien;
525
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
526

    
527

    
528
--
529
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
530
--
531

    
532
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
533
REVOKE ALL ON TABLE tnrs FROM bien;
534
GRANT ALL ON TABLE tnrs TO bien;
535
GRANT SELECT ON TABLE tnrs TO bien_read;
536

    
537

    
538
--
539
-- PostgreSQL database dump complete
540
--
541

    
(8-8/10)