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
    new.is_valid_match = COALESCE("TNRS".score_ok(new."Max_score"), false)
140
        AND COALESCE(new."Is_plant", false);
141
    
142
    RETURN new;
143
END;
144
$$;
145

    
146

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

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

    
157

    
158
SET default_tablespace = '';
159

    
160
SET default_with_oids = false;
161

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

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

    
211

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

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

    
219

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

    
224
CREATE VIEW "AcceptedTaxon" AS
225
    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;
226

    
227

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

    
232
CREATE VIEW "MatchedTaxon" AS
233
    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;
234

    
235

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

    
240
CREATE VIEW "ValidMatchedTaxon" AS
241
    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;
242

    
243

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

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

    
250

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

    
255
CREATE VIEW "ScrubbedTaxon" AS
256
    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");
257

    
258

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

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

    
265

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

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

    
276

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

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

    
283

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

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

    
290

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

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

    
302

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

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

    
324

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

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

    
331

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

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

    
343

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

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

    
350

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

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

    
357

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

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

    
364

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

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

    
371

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

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

    
383

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

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

    
391

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

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

    
399

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

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

    
407

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

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

    
415

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

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

    
423

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

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

    
431

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

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

    
439

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

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

    
447

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

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

    
455

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

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

    
462

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

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

    
469

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

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

    
476

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

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

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

    
485

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

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

    
492

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

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

    
500

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

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

    
508

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

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

    
516

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

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

    
526

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

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

    
536

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

    
(8-8/10)