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 = COALESCE(CASE
128
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
129
			THEN true
130
		ELSE -- consider genus
131
			(CASE
132
			WHEN new."Genus_score" =  1	   -- exact match
133
				THEN
134
				(CASE
135
				WHEN NOT genus_is_homonym THEN true
136
				ELSE "Specific_epithet_is_plant"
137
				END)
138
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
139
				THEN "Specific_epithet_is_plant"
140
			ELSE NULL -- ambiguous
141
			END)
142
		END, false);
143
	new.scrubbed_unique_taxon_name = COALESCE(
144
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
145
	
146
	RETURN new;
147
END;
148
$$;
149

    
150

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

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

    
161

    
162
SET default_tablespace = '';
163

    
164
SET default_with_oids = false;
165

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

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

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

    
259

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

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

    
299

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

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

    
306

    
307
--
308
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
309
--
310

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

    
318

    
319
--
320
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
321
--
322

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

    
340

    
341
--
342
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
343
--
344

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

    
347

    
348
--
349
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
350
--
351

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

    
359

    
360
--
361
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
362
--
363

    
364
COMMENT ON TABLE client_version IS 'contains svn revisions';
365

    
366

    
367
--
368
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
369
--
370

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

    
373

    
374
--
375
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
376
--
377

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

    
380

    
381
--
382
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
383
--
384

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

    
387

    
388
--
389
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
390
--
391

    
392
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
393
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
394
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
395
    tnrs."Name_matched_accepted_family" AS scrubbed_family, 
396
    tnrs."Genus_matched" AS scrubbed_genus, 
397
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
398
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
399
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
400
    tnrs."Name_matched_author" AS scrubbed_author, 
401
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author
402
   FROM tnrs;
403

    
404

    
405
--
406
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
407
--
408

    
409
CREATE VIEW taxon_scrub AS
410
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
411
    "ValidMatchedTaxon"."*Name_matched.batch", 
412
    "ValidMatchedTaxon"."concatenatedScientificName", 
413
    "ValidMatchedTaxon"."matchedTaxonName", 
414
    "ValidMatchedTaxon"."matchedTaxonRank", 
415
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
416
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
417
    "ValidMatchedTaxon"."matchedScientificNameID", 
418
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
419
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
420
    "ValidMatchedTaxon"."matchedFamily", 
421
    "ValidMatchedTaxon"."matchedGenus", 
422
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
423
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
424
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
425
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
426
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
427
    "ValidMatchedTaxon"."identificationQualifier", 
428
    "ValidMatchedTaxon"."morphospeciesSuffix", 
429
    "ValidMatchedTaxon"."taxonomicStatus", 
430
    "ValidMatchedTaxon"."acceptedTaxonName", 
431
    "ValidMatchedTaxon"."acceptedScientificNameAuthorship", 
432
    "ValidMatchedTaxon"."acceptedTaxonRank", 
433
    "ValidMatchedTaxon"."acceptedScientificNameID", 
434
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_species", 
435
    "ValidMatchedTaxon"."acceptedFamily", 
436
    "ValidMatchedTaxon"."*Name_matched.Selected", 
437
    "ValidMatchedTaxon"."*Name_matched.Source", 
438
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
439
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
440
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
441
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
442
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
443
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
444
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
445
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
446
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
447
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
448
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author
449
   FROM ("ValidMatchedTaxon"
450
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
451

    
452

    
453
--
454
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
455
--
456

    
457
COMMENT ON VIEW taxon_scrub IS 'to update, use * as the column list';
458

    
459

    
460
--
461
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
462
--
463

    
464
ALTER TABLE ONLY batch_download_settings
465
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
466

    
467

    
468
--
469
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
470
--
471

    
472
ALTER TABLE ONLY batch
473
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
474

    
475

    
476
--
477
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
478
--
479

    
480
ALTER TABLE ONLY batch
481
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
482

    
483

    
484
--
485
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
486
--
487

    
488
ALTER TABLE ONLY client_version
489
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
490

    
491

    
492
--
493
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
494
--
495

    
496
ALTER TABLE ONLY tnrs
497
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
498

    
499

    
500
--
501
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
502
--
503

    
504
ALTER TABLE ONLY tnrs
505
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
506

    
507

    
508
--
509
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
510
--
511

    
512
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
513

    
514

    
515
--
516
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
517
--
518

    
519
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
520

    
521

    
522
--
523
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
524
--
525

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

    
528

    
529
--
530
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
531
--
532

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

    
535

    
536
--
537
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
538
--
539

    
540
ALTER TABLE ONLY batch
541
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
542

    
543

    
544
--
545
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
546
--
547

    
548
ALTER TABLE ONLY batch_download_settings
549
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
550

    
551

    
552
--
553
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
554
--
555

    
556
ALTER TABLE ONLY tnrs
557
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
558

    
559

    
560
--
561
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
562
--
563

    
564
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
565
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
566
GRANT ALL ON SCHEMA "TNRS" TO bien;
567
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
568

    
569

    
570
--
571
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
572
--
573

    
574
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
575
REVOKE ALL ON TABLE tnrs FROM bien;
576
GRANT ALL ON TABLE tnrs TO bien;
577
GRANT SELECT ON TABLE tnrs TO bien_read;
578

    
579

    
580
--
581
-- PostgreSQL database dump complete
582
--
583

    
(8-8/10)