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
SET search_path = "TNRS", pg_catalog;
19

    
20
--
21
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
22
--
23

    
24
CREATE FUNCTION batch__fill() RETURNS trigger
25
    LANGUAGE plpgsql
26
    AS $$
27
BEGIN
28
	new.id_by_time = new.time_submitted;
29
	new.id = COALESCE(new.id, new.id_by_time);
30
	RETURN new;
31
END;
32
$$;
33

    
34

    
35
--
36
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
37
--
38

    
39
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
40
    LANGUAGE sql STABLE STRICT
41
    AS $_$
42
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
43
$_$;
44

    
45

    
46
--
47
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
48
--
49

    
50
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
51
    LANGUAGE sql STABLE STRICT
52
    AS $_$
53
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
54
$_$;
55

    
56

    
57
--
58
-- Name: score_ok(double precision); Type: FUNCTION; Schema: TNRS; Owner: -
59
--
60

    
61
CREATE FUNCTION score_ok(score double precision) RETURNS boolean
62
    LANGUAGE sql IMMUTABLE STRICT
63
    AS $_$
64
SELECT $1 >= 0.8
65
$_$;
66

    
67

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

    
72
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
73
    LANGUAGE plpgsql
74
    AS $$
75
DECLARE
76
    "Specific_epithet_is_plant" boolean :=
77
        (CASE
78
        WHEN   new."Infraspecific_epithet_matched"   IS NOT NULL
79
            OR new."Infraspecific_epithet_2_matched" IS NOT NULL
80
            OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
81
            THEN true
82
        ELSE NULL -- ambiguous
83
        END);
84
    never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false); -- author disambiguates
85
    family_is_homonym boolean = NOT never_homonym AND "TNRS".family_is_homonym(new."Family_matched");
86
    genus_is_homonym  boolean = NOT never_homonym AND "TNRS".genus_is_homonym( new."Genus_matched" );
87
BEGIN
88
    new."Accepted_scientific_name" = NULLIF(concat_ws(' '
89
        , NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'), new."Accepted_name")
90
        , new."Accepted_name"
91
        , new."Accepted_name_author"
92
    ), '');
93
    new."Max_score" = GREATEST(
94
          new."Overall_score"
95
        , new."Family_score"
96
        , new."Genus_score"
97
        , new."Specific_epithet_score"
98
    );
99
    new."Is_homonym" = COALESCE(genus_is_homonym, family_is_homonym);
100
    new."Is_plant" = (CASE
101
        WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
102
            THEN true
103
        ELSE -- consider genus
104
            (CASE
105
            WHEN new."Genus_score" =  1    -- exact match
106
                THEN
107
                (CASE
108
                WHEN NOT genus_is_homonym THEN true
109
                ELSE "Specific_epithet_is_plant"
110
                END)
111
            WHEN new."Genus_score" >= 0.85 -- fuzzy match
112
                THEN "Specific_epithet_is_plant"
113
            ELSE NULL -- ambiguous
114
            END)
115
        END);
116
    new.is_valid_match = COALESCE("TNRS".score_ok(new."Max_score"), false)
117
        AND COALESCE(new."Is_plant", false);
118
    
119
    RETURN new;
120
END;
121
$$;
122

    
123

    
124
--
125
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
126
--
127

    
128
COMMENT ON FUNCTION tnrs_populate_fields() IS 'IMPORTANT: when changing this function, you must regenerate the derived cols:
129
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
130
runtime: 25 min ("5221748 rows affected, 1524228 ms execution time")
131
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
132
runtime: 1 min ("62350 ms")';
133

    
134

    
135
SET default_tablespace = '';
136

    
137
SET default_with_oids = false;
138

    
139
--
140
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
141
--
142

    
143
CREATE TABLE tnrs (
144
    batch text DEFAULT now() NOT NULL,
145
    "Name_number" integer NOT NULL,
146
    "Name_submitted" text NOT NULL,
147
    "Overall_score" double precision,
148
    "Name_matched" text,
149
    "Name_matched_rank" text,
150
    "Name_score" double precision,
151
    "Name_matched_author" text,
152
    "Name_matched_url" text,
153
    "Author_matched" text,
154
    "Author_score" double precision,
155
    "Family_matched" text,
156
    "Family_score" double precision,
157
    "Name_matched_accepted_family" text,
158
    "Genus_matched" text,
159
    "Genus_score" double precision,
160
    "Specific_epithet_matched" text,
161
    "Specific_epithet_score" double precision,
162
    "Infraspecific_rank" text,
163
    "Infraspecific_epithet_matched" text,
164
    "Infraspecific_epithet_score" double precision,
165
    "Infraspecific_rank_2" text,
166
    "Infraspecific_epithet_2_matched" text,
167
    "Infraspecific_epithet_2_score" double precision,
168
    "Annotations" text,
169
    "Unmatched_terms" text,
170
    "Taxonomic_status" text,
171
    "Accepted_name" text,
172
    "Accepted_name_author" text,
173
    "Accepted_name_rank" text,
174
    "Accepted_name_url" text,
175
    "Accepted_name_species" text,
176
    "Accepted_name_family" text,
177
    "Selected" text,
178
    "Source" text,
179
    "Warnings" text,
180
    "Accepted_name_lsid" text,
181
    "Accepted_scientific_name" text,
182
    "Max_score" double precision,
183
    "Is_homonym" boolean,
184
    "Is_plant" boolean,
185
    is_valid_match boolean NOT NULL
186
);
187

    
188

    
189
--
190
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
191
--
192

    
193
COMMENT ON TABLE tnrs IS 'IMPORTANT: when changing this table''s schema, you may need to re-run TNRS:
194
$ inputs/.TNRS/data.sql.run refresh
195
you must also make the same changes on vegbiendev: e.g.
196
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
197
SELECT util.set_col_types(''"TNRS".tnrs'', ARRAY[
198
  (''col'', ''new_type'')
199
]::util.col_cast[]);
200
runtime: 9 min ("531282 ms")';
201

    
202

    
203
--
204
-- Name: AcceptedTaxon; Type: VIEW; Schema: TNRS; Owner: -
205
--
206

    
207
CREATE VIEW "AcceptedTaxon" AS
208
    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;
209

    
210

    
211
--
212
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
213
--
214

    
215
CREATE VIEW "MatchedTaxon" AS
216
    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" FROM tnrs;
217

    
218

    
219
--
220
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
221
--
222

    
223
CREATE VIEW "ValidMatchedTaxon" AS
224
    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" FROM "MatchedTaxon" WHERE score_ok("MatchedTaxon"."matchedTaxonConfidence_fraction");
225

    
226

    
227
--
228
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
229
--
230

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

    
233

    
234
--
235
-- Name: ScrubbedTaxon; Type: VIEW; Schema: TNRS; Owner: -
236
--
237

    
238
CREATE VIEW "ScrubbedTaxon" AS
239
    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");
240

    
241

    
242
--
243
-- Name: VIEW "ScrubbedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
244
--
245

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

    
248

    
249
--
250
-- Name: Source; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
251
--
252

    
253
CREATE TABLE "Source" (
254
    "*row_num" integer NOT NULL,
255
    "sourceType" text DEFAULT 'aggregator'::text NOT NULL,
256
    "datasetURL" text DEFAULT 'http://tnrs.iplantcollaborative.org/TNRSapp.html'::text NOT NULL
257
);
258

    
259

    
260
--
261
-- Name: COLUMN "Source"."sourceType"; Type: COMMENT; Schema: TNRS; Owner: -
262
--
263

    
264
COMMENT ON COLUMN "Source"."sourceType" IS 'constant';
265

    
266

    
267
--
268
-- Name: COLUMN "Source"."datasetURL"; Type: COMMENT; Schema: TNRS; Owner: -
269
--
270

    
271
COMMENT ON COLUMN "Source"."datasetURL" IS 'constant';
272

    
273

    
274
--
275
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
276
--
277

    
278
CREATE TABLE batch (
279
    id text NOT NULL,
280
    id_by_time text,
281
    time_submitted timestamp with time zone DEFAULT now(),
282
    client_version text
283
);
284

    
285

    
286
--
287
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
288
--
289

    
290
CREATE TABLE batch_download_settings (
291
    id text NOT NULL,
292
    "E-mail" text,
293
    "Id" text,
294
    "Job type" text,
295
    "Contains Id" boolean,
296
    "Start time" text,
297
    "Finish time" text,
298
    "TNRS version" text,
299
    "Sources selected" text,
300
    "Match threshold" double precision,
301
    "Classification" text,
302
    "Allow partial matches?" boolean,
303
    "Sort by source" boolean,
304
    "Constrain by higher taxonomy" boolean
305
);
306

    
307

    
308
--
309
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
310
--
311

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

    
314

    
315
--
316
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
317
--
318

    
319
CREATE TABLE client_version (
320
    id text NOT NULL,
321
    global_rev integer NOT NULL,
322
    "/lib/tnrs.py rev" integer,
323
    "/bin/tnrs_db rev" integer
324
);
325

    
326

    
327
--
328
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
329
--
330

    
331
COMMENT ON TABLE client_version IS 'contains svn revisions';
332

    
333

    
334
--
335
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
336
--
337

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

    
340

    
341
--
342
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
343
--
344

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

    
347

    
348
--
349
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
350
--
351

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

    
354

    
355
--
356
-- Name: ~Source.map; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
357
--
358

    
359
CREATE TABLE "~Source.map" (
360
    "from" text NOT NULL,
361
    "to" text,
362
    filter text,
363
    notes text
364
);
365

    
366

    
367
--
368
-- Name: Source_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
369
--
370

    
371
ALTER TABLE ONLY "Source"
372
    ADD CONSTRAINT "Source_pkey" PRIMARY KEY ("*row_num");
373

    
374

    
375
--
376
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
377
--
378

    
379
ALTER TABLE ONLY batch_download_settings
380
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
381

    
382

    
383
--
384
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
385
--
386

    
387
ALTER TABLE ONLY batch
388
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
389

    
390

    
391
--
392
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
393
--
394

    
395
ALTER TABLE ONLY batch
396
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
397

    
398

    
399
--
400
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
401
--
402

    
403
ALTER TABLE ONLY client_version
404
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
405

    
406

    
407
--
408
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
409
--
410

    
411
ALTER TABLE ONLY tnrs
412
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
413

    
414

    
415
--
416
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
417
--
418

    
419
ALTER TABLE ONLY tnrs
420
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
421

    
422

    
423
--
424
-- Name: ~Source.map_from_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
425
--
426

    
427
ALTER TABLE ONLY "~Source.map"
428
    ADD CONSTRAINT "~Source.map_from_key" UNIQUE ("from");
429

    
430

    
431
--
432
-- Name: ~Source.map_to_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
433
--
434

    
435
ALTER TABLE ONLY "~Source.map"
436
    ADD CONSTRAINT "~Source.map_to_key" UNIQUE ("to");
437

    
438

    
439
--
440
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
441
--
442

    
443
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
444

    
445

    
446
--
447
-- Name: tnrs_score_ok; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
448
--
449

    
450
CREATE UNIQUE INDEX tnrs_score_ok ON tnrs USING btree ("Name_submitted") WHERE score_ok("Max_score");
451

    
452

    
453
--
454
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
455
--
456

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

    
459

    
460
--
461
-- Name: map_filter_insert; Type: TRIGGER; Schema: TNRS; Owner: -
462
--
463

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

    
466
ALTER TABLE "~Source.map" DISABLE TRIGGER map_filter_insert;
467

    
468

    
469
--
470
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
471
--
472

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

    
475

    
476
--
477
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
478
--
479

    
480
ALTER TABLE ONLY batch
481
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
482

    
483

    
484
--
485
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
486
--
487

    
488
ALTER TABLE ONLY batch_download_settings
489
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
490

    
491

    
492
--
493
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
494
--
495

    
496
ALTER TABLE ONLY tnrs
497
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
498

    
499

    
500
--
501
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
502
--
503

    
504
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
505
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
506
GRANT ALL ON SCHEMA "TNRS" TO bien;
507
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
508

    
509

    
510
--
511
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
512
--
513

    
514
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
515
REVOKE ALL ON TABLE tnrs FROM bien;
516
GRANT ALL ON TABLE tnrs TO bien;
517
GRANT SELECT ON TABLE tnrs TO bien_read;
518

    
519

    
520
--
521
-- PostgreSQL database dump complete
522
--
523

    
(8-8/10)