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

    
41

    
42
SET search_path = "TNRS", pg_catalog;
43

    
44
--
45
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
46
--
47

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

    
58

    
59
--
60
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
61
--
62

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

    
69

    
70
--
71
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
72
--
73

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

    
80

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

    
85
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
86
    LANGUAGE sql IMMUTABLE
87
    AS $_$
88
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
89
"taxonomic_status should be accepted instead of synonym when an accepted name is
90
available (this is not always the case when a name is marked as a synonym)" */
91
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
92
$_$;
93

    
94

    
95
--
96
-- Name: taxon_match__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
97
--
98

    
99
CREATE FUNCTION taxon_match__batch_begin() RETURNS trigger
100
    LANGUAGE plpgsql
101
    AS $$
102
BEGIN
103
	PERFORM util.seq__reset('pg_temp.taxon_match__match_num__seq', 0);
104
	RETURN NULL;
105
END;
106
$$;
107

    
108

    
109
--
110
-- Name: taxon_match__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
111
--
112

    
113
CREATE FUNCTION taxon_match__fill() RETURNS trigger
114
    LANGUAGE plpgsql
115
    AS $$
116
BEGIN
117
	DECLARE
118
		"Specific_epithet_is_plant" boolean :=
119
			(CASE
120
			WHEN   new."*Infraspecific_epithet_matched"	 IS NOT NULL
121
				OR new."*Infraspecific_epithet_2_matched" IS NOT NULL
122
				OR new."*Specific_epithet_score" >= 0.9 -- fuzzy match
123
				THEN true
124
			ELSE NULL -- ambiguous
125
			END);
126
		never_homonym boolean = COALESCE(new."*Author_score" >= 0.6, false);
127
			-- author disambiguates
128
		family_is_homonym boolean = NOT never_homonym
129
			AND "TNRS".family_is_homonym(new."*Family_matched");
130
		genus_is_homonym  boolean = NOT never_homonym
131
			AND "TNRS".genus_is_homonym(new."*Genus_matched");
132
	BEGIN
133
		/* exclude homonyms because these are not valid matches (TNRS provides a
134
		name, but the name is not meaningful because it is not unambiguous) */
135
		new.is_valid_match = new."*Taxonomic_status" != 'Invalid'
136
			AND COALESCE(CASE
137
			WHEN new."*Family_score" = 1 AND NOT family_is_homonym -- exact match
138
				THEN true
139
			ELSE -- consider genus
140
				(CASE
141
				WHEN new."*Genus_score" =  1	   -- exact match
142
					THEN
143
					(CASE
144
					WHEN NOT genus_is_homonym THEN true
145
					ELSE "Specific_epithet_is_plant"
146
					END)
147
				WHEN new."*Genus_score" >= 0.85 -- fuzzy match
148
					THEN "Specific_epithet_is_plant"
149
				ELSE NULL -- ambiguous
150
				END)
151
			END, false);
152
	END;
153
	
154
	DECLARE
155
		matched_taxon_name_with_author text = NULLIF(concat_ws(' '
156
			, NULLIF(NULLIF(new."*Name_matched_accepted_family", 'Unknown'),
157
				new."*Name_matched")
158
			, NULLIF(new."*Name_matched", 'No suitable matches found.')
159
			, new."*Name_matched_author"
160
			), '');
161
		accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
162
			, NULLIF(NULLIF(new."*Accepted_name_family", 'Unknown'),
163
				new."*Accepted_name")
164
			, new."*Accepted_name"
165
			, new."*Accepted_name_author"
166
			), '');
167
	BEGIN
168
		new.scrubbed_unique_taxon_name = COALESCE(
169
			accepted_taxon_name_with_author, matched_taxon_name_with_author);
170
	END;
171
	
172
	RETURN new;
173
END;
174
$$;
175

    
176

    
177
--
178
-- Name: FUNCTION taxon_match__fill(); Type: COMMENT; Schema: TNRS; Owner: -
179
--
180

    
181
COMMENT ON FUNCTION taxon_match__fill() IS '
182
IMPORTANT: when changing this function, you must regenerate the derived cols:
183
UPDATE "TNRS".taxon_match SET "Name_submitted" = "Name_submitted"
184
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
185
VACUUM ANALYZE "TNRS".taxon_match -- to remove previous rows
186
runtime: 1.5 min ("92633 ms")
187
';
188

    
189

    
190
--
191
-- Name: taxon_match__fill_derived(); Type: FUNCTION; Schema: TNRS; Owner: -
192
--
193

    
194
CREATE FUNCTION taxon_match__fill_derived() RETURNS trigger
195
    LANGUAGE plpgsql
196
    AS $$
197
BEGIN
198
	new."__accepted_{genus,specific_epithet}" = (SELECT
199
		regexp_split_to_array("*Accepted_name_species", ' ')
200
		FROM (SELECT new.*) new);
201
	
202
	RETURN new;
203
END;
204
$$;
205

    
206

    
207
--
208
-- Name: taxon_match__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
209
--
210

    
211
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
212
    LANGUAGE plpgsql
213
    AS $$
214
BEGIN
215
	IF new.match_num IS NULL THEN
216
		new.match_num = "TNRS".taxon_match__match_num__next();
217
	END IF;
218
	RETURN new;
219
END;
220
$$;
221

    
222

    
223
--
224
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
225
--
226

    
227
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
228
    LANGUAGE sql
229
    AS $$
230
SELECT nextval('pg_temp.taxon_match__match_num__seq');
231
$$;
232

    
233

    
234
--
235
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
236
--
237

    
238
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
239
    LANGUAGE plpgsql
240
    AS $$
241
BEGIN
242
	INSERT INTO "TNRS".taxon_match_input SELECT new.*;
243
	RETURN NULL;
244
END;
245
$$;
246

    
247

    
248
--
249
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
250
--
251

    
252
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
253
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
256
$_$;
257

    
258

    
259
--
260
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
261
--
262

    
263
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
264
    LANGUAGE sql IMMUTABLE
265
    AS $$
266
SELECT ARRAY[
267
]::text[]
268
$$;
269

    
270

    
271
SET default_tablespace = '';
272

    
273
SET default_with_oids = false;
274

    
275
--
276
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
277
--
278

    
279
CREATE TABLE taxon_match (
280
    batch text DEFAULT now() NOT NULL,
281
    match_num integer NOT NULL,
282
    "*Name_number" integer NOT NULL,
283
    "*Name_submitted" text NOT NULL,
284
    "*Overall_score" double precision,
285
    "*Name_matched" text,
286
    "*Name_matched_rank" text,
287
    "*Name_score" double precision,
288
    "*Name_matched_author" text,
289
    "*Name_matched_url" text,
290
    "*Author_matched" text,
291
    "*Author_score" double precision,
292
    "*Family_matched" text,
293
    "*Family_score" double precision,
294
    "*Name_matched_accepted_family" text,
295
    "*Genus_matched" text,
296
    "*Genus_score" double precision,
297
    "*Specific_epithet_matched" text,
298
    "*Specific_epithet_score" double precision,
299
    "*Infraspecific_rank" text,
300
    "*Infraspecific_epithet_matched" text,
301
    "*Infraspecific_epithet_score" double precision,
302
    "*Infraspecific_rank_2" text,
303
    "*Infraspecific_epithet_2_matched" text,
304
    "*Infraspecific_epithet_2_score" double precision,
305
    "*Annotations" text,
306
    "*Unmatched_terms" text,
307
    "*Taxonomic_status" text,
308
    "*Accepted_name" text,
309
    "*Accepted_name_author" text,
310
    "*Accepted_name_rank" text,
311
    "*Accepted_name_url" text,
312
    "*Accepted_name_species" text,
313
    "*Accepted_name_family" text,
314
    "*Selected" text,
315
    "*Source" text,
316
    "*Warnings" text,
317
    "*Accepted_name_lsid" text,
318
    is_valid_match boolean NOT NULL,
319
    scrubbed_unique_taxon_name text,
320
    "__accepted_{genus,specific_epithet}" text[],
321
    CONSTRAINT "__accepted_{genus,specific_epithet}" CHECK ((NOT ("__accepted_{genus,specific_epithet}" IS DISTINCT FROM regexp_split_to_array("*Accepted_name_species", ' '::text))))
322
);
323

    
324

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

    
329
COMMENT ON TABLE taxon_match IS '
330
to remove columns or add columns at the end:
331
$ rm=1 inputs/.TNRS/data.sql.run
332
$ make schemas/remake
333

    
334
to add columns in the middle:
335
make the changes in inputs/.TNRS/schema.sql
336
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
337
$ make schemas/remake
338

    
339
to populate a new column:
340
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
341
UPDATE "TNRS".taxon_match SET "col" = value;
342
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
343
CLUSTER "TNRS".taxon_match; -- ensure rows are exported in sorted order
344
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
345
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
346

    
347
to add a constraint: runtime: 3 min ("173620 ms")
348
';
349

    
350

    
351
--
352
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
353
--
354

    
355
CREATE VIEW taxon_best_match AS
356
 SELECT taxon_match.batch,
357
    taxon_match.match_num,
358
    taxon_match."*Name_number",
359
    taxon_match."*Name_submitted",
360
    taxon_match."*Overall_score",
361
    taxon_match."*Name_matched",
362
    taxon_match."*Name_matched_rank",
363
    taxon_match."*Name_score",
364
    taxon_match."*Name_matched_author",
365
    taxon_match."*Name_matched_url",
366
    taxon_match."*Author_matched",
367
    taxon_match."*Author_score",
368
    taxon_match."*Family_matched",
369
    taxon_match."*Family_score",
370
    taxon_match."*Name_matched_accepted_family",
371
    taxon_match."*Genus_matched",
372
    taxon_match."*Genus_score",
373
    taxon_match."*Specific_epithet_matched",
374
    taxon_match."*Specific_epithet_score",
375
    taxon_match."*Infraspecific_rank",
376
    taxon_match."*Infraspecific_epithet_matched",
377
    taxon_match."*Infraspecific_epithet_score",
378
    taxon_match."*Infraspecific_rank_2",
379
    taxon_match."*Infraspecific_epithet_2_matched",
380
    taxon_match."*Infraspecific_epithet_2_score",
381
    taxon_match."*Annotations",
382
    taxon_match."*Unmatched_terms",
383
    taxon_match."*Taxonomic_status",
384
    taxon_match."*Accepted_name",
385
    taxon_match."*Accepted_name_author",
386
    taxon_match."*Accepted_name_rank",
387
    taxon_match."*Accepted_name_url",
388
    taxon_match."*Accepted_name_species",
389
    taxon_match."*Accepted_name_family",
390
    taxon_match."*Selected",
391
    taxon_match."*Source",
392
    taxon_match."*Warnings",
393
    taxon_match."*Accepted_name_lsid",
394
    taxon_match.is_valid_match,
395
    taxon_match.scrubbed_unique_taxon_name
396
   FROM taxon_match
397
  WHERE (taxon_match."*Selected" = 'true'::text);
398

    
399

    
400
--
401
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
402
--
403

    
404
COMMENT ON VIEW taxon_best_match IS '
405
to modify:
406
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
407
SELECT __
408
$$);
409
';
410

    
411

    
412
--
413
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
414
--
415

    
416
CREATE VIEW "MatchedTaxon" AS
417
 SELECT taxon_best_match.batch,
418
    taxon_best_match.match_num,
419
    taxon_best_match."*Name_number",
420
    taxon_best_match."*Name_submitted",
421
    taxon_best_match."*Overall_score",
422
    taxon_best_match."*Name_matched",
423
    taxon_best_match."*Name_matched_rank",
424
    taxon_best_match."*Name_score",
425
    taxon_best_match."*Name_matched_author",
426
    taxon_best_match."*Name_matched_url",
427
    taxon_best_match."*Author_matched",
428
    taxon_best_match."*Author_score",
429
    taxon_best_match."*Family_matched",
430
    taxon_best_match."*Family_score",
431
    taxon_best_match."*Name_matched_accepted_family",
432
    taxon_best_match."*Genus_matched",
433
    taxon_best_match."*Genus_score",
434
    taxon_best_match."*Specific_epithet_matched",
435
    taxon_best_match."*Specific_epithet_score",
436
    taxon_best_match."*Infraspecific_rank",
437
    taxon_best_match."*Infraspecific_epithet_matched",
438
    taxon_best_match."*Infraspecific_epithet_score",
439
    taxon_best_match."*Infraspecific_rank_2",
440
    taxon_best_match."*Infraspecific_epithet_2_matched",
441
    taxon_best_match."*Infraspecific_epithet_2_score",
442
    taxon_best_match."*Annotations",
443
    taxon_best_match."*Unmatched_terms",
444
    taxon_best_match."*Taxonomic_status",
445
    taxon_best_match."*Accepted_name",
446
    taxon_best_match."*Accepted_name_author",
447
    taxon_best_match."*Accepted_name_rank",
448
    taxon_best_match."*Accepted_name_url",
449
    taxon_best_match."*Accepted_name_species",
450
    taxon_best_match."*Accepted_name_family",
451
    taxon_best_match."*Selected",
452
    taxon_best_match."*Source",
453
    taxon_best_match."*Warnings",
454
    taxon_best_match."*Accepted_name_lsid",
455
    taxon_best_match.is_valid_match,
456
    taxon_best_match.scrubbed_unique_taxon_name,
457
    map_taxonomic_status(taxon_best_match."*Taxonomic_status", taxon_best_match."*Accepted_name") AS "taxonomicStatus",
458
        CASE
459
            WHEN (taxon_best_match."*Accepted_name_rank" = 'family'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name_family", taxon_best_match."*Unmatched_terms")
460
            WHEN (taxon_best_match."*Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name", taxon_best_match."*Unmatched_terms")
461
            ELSE taxon_best_match."*Accepted_name_species"
462
        END AS accepted_morphospecies_binomial
463
   FROM taxon_best_match;
464

    
465

    
466
--
467
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
468
--
469

    
470
COMMENT ON VIEW "MatchedTaxon" IS '
471
to modify:
472
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
473
SELECT __
474
$$);
475
';
476

    
477

    
478
--
479
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
480
--
481

    
482
CREATE VIEW "ValidMatchedTaxon" AS
483
 SELECT "MatchedTaxon".batch,
484
    "MatchedTaxon".match_num,
485
    "MatchedTaxon"."*Name_number",
486
    "MatchedTaxon"."*Name_submitted",
487
    "MatchedTaxon"."*Overall_score",
488
    "MatchedTaxon"."*Name_matched",
489
    "MatchedTaxon"."*Name_matched_rank",
490
    "MatchedTaxon"."*Name_score",
491
    "MatchedTaxon"."*Name_matched_author",
492
    "MatchedTaxon"."*Name_matched_url",
493
    "MatchedTaxon"."*Author_matched",
494
    "MatchedTaxon"."*Author_score",
495
    "MatchedTaxon"."*Family_matched",
496
    "MatchedTaxon"."*Family_score",
497
    "MatchedTaxon"."*Name_matched_accepted_family",
498
    "MatchedTaxon"."*Genus_matched",
499
    "MatchedTaxon"."*Genus_score",
500
    "MatchedTaxon"."*Specific_epithet_matched",
501
    "MatchedTaxon"."*Specific_epithet_score",
502
    "MatchedTaxon"."*Infraspecific_rank",
503
    "MatchedTaxon"."*Infraspecific_epithet_matched",
504
    "MatchedTaxon"."*Infraspecific_epithet_score",
505
    "MatchedTaxon"."*Infraspecific_rank_2",
506
    "MatchedTaxon"."*Infraspecific_epithet_2_matched",
507
    "MatchedTaxon"."*Infraspecific_epithet_2_score",
508
    "MatchedTaxon"."*Annotations",
509
    "MatchedTaxon"."*Unmatched_terms",
510
    "MatchedTaxon"."*Taxonomic_status",
511
    "MatchedTaxon"."*Accepted_name",
512
    "MatchedTaxon"."*Accepted_name_author",
513
    "MatchedTaxon"."*Accepted_name_rank",
514
    "MatchedTaxon"."*Accepted_name_url",
515
    "MatchedTaxon"."*Accepted_name_species",
516
    "MatchedTaxon"."*Accepted_name_family",
517
    "MatchedTaxon"."*Selected",
518
    "MatchedTaxon"."*Source",
519
    "MatchedTaxon"."*Warnings",
520
    "MatchedTaxon"."*Accepted_name_lsid",
521
    "MatchedTaxon".is_valid_match,
522
    "MatchedTaxon".scrubbed_unique_taxon_name,
523
    "MatchedTaxon"."taxonomicStatus",
524
    "MatchedTaxon".accepted_morphospecies_binomial
525
   FROM "MatchedTaxon"
526
  WHERE "MatchedTaxon".is_valid_match;
527

    
528

    
529
--
530
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
531
--
532

    
533
COMMENT ON VIEW "ValidMatchedTaxon" IS '
534
to update, use * as the column list
535
';
536

    
537

    
538
--
539
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
540
--
541

    
542
CREATE TABLE batch (
543
    id text NOT NULL,
544
    id_by_time text,
545
    time_submitted timestamp with time zone DEFAULT now(),
546
    client_version text
547
);
548

    
549

    
550
--
551
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
552
--
553

    
554
CREATE TABLE batch_download_settings (
555
    id text NOT NULL,
556
    "E-mail" text,
557
    "Id" text,
558
    "Job type" text,
559
    "Contains Id" boolean,
560
    "Start time" text,
561
    "Finish time" text,
562
    "TNRS version" text,
563
    "Sources selected" text,
564
    "Match threshold" double precision,
565
    "Classification" text,
566
    "Allow partial matches?" boolean,
567
    "Sort by source" boolean,
568
    "Constrain by higher taxonomy" boolean
569
);
570

    
571

    
572
--
573
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
574
--
575

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

    
580

    
581
--
582
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
583
--
584

    
585
CREATE TABLE client_version (
586
    id text NOT NULL,
587
    global_rev integer NOT NULL,
588
    "/lib/tnrs.py rev" integer,
589
    "/bin/tnrs_db rev" integer
590
);
591

    
592

    
593
--
594
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
595
--
596

    
597
COMMENT ON TABLE client_version IS '
598
contains svn revisions
599
';
600

    
601

    
602
--
603
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
604
--
605

    
606
COMMENT ON COLUMN client_version.global_rev IS '
607
from `svn info .` > Last Changed Rev
608
';
609

    
610

    
611
--
612
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
613
--
614

    
615
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
616
from `svn info lib/tnrs.py` > Last Changed Rev
617
';
618

    
619

    
620
--
621
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
622
--
623

    
624
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
625
from `svn info bin/tnrs_db` > Last Changed Rev
626
';
627

    
628

    
629
--
630
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
631
--
632

    
633
CREATE VIEW taxon_match_input AS
634
 SELECT taxon_match."*Name_number" AS "Name_number",
635
    taxon_match."*Name_submitted" AS "Name_submitted",
636
    taxon_match."*Overall_score" AS "Overall_score",
637
    taxon_match."*Name_matched" AS "Name_matched",
638
    taxon_match."*Name_matched_rank" AS "Name_matched_rank",
639
    taxon_match."*Name_score" AS "Name_score",
640
    taxon_match."*Name_matched_author" AS "Name_matched_author",
641
    taxon_match."*Name_matched_url" AS "Name_matched_url",
642
    taxon_match."*Author_matched" AS "Author_matched",
643
    taxon_match."*Author_score" AS "Author_score",
644
    taxon_match."*Family_matched" AS "Family_matched",
645
    taxon_match."*Family_score" AS "Family_score",
646
    taxon_match."*Name_matched_accepted_family" AS "Name_matched_accepted_family",
647
    taxon_match."*Genus_matched" AS "Genus_matched",
648
    taxon_match."*Genus_score" AS "Genus_score",
649
    taxon_match."*Specific_epithet_matched" AS "Specific_epithet_matched",
650
    taxon_match."*Specific_epithet_score" AS "Specific_epithet_score",
651
    taxon_match."*Infraspecific_rank" AS "Infraspecific_rank",
652
    taxon_match."*Infraspecific_epithet_matched" AS "Infraspecific_epithet_matched",
653
    taxon_match."*Infraspecific_epithet_score" AS "Infraspecific_epithet_score",
654
    taxon_match."*Infraspecific_rank_2" AS "Infraspecific_rank_2",
655
    taxon_match."*Infraspecific_epithet_2_matched" AS "Infraspecific_epithet_2_matched",
656
    taxon_match."*Infraspecific_epithet_2_score" AS "Infraspecific_epithet_2_score",
657
    taxon_match."*Annotations" AS "Annotations",
658
    taxon_match."*Unmatched_terms" AS "Unmatched_terms",
659
    taxon_match."*Taxonomic_status" AS "Taxonomic_status",
660
    taxon_match."*Accepted_name" AS "Accepted_name",
661
    taxon_match."*Accepted_name_author" AS "Accepted_name_author",
662
    taxon_match."*Accepted_name_rank" AS "Accepted_name_rank",
663
    taxon_match."*Accepted_name_url" AS "Accepted_name_url",
664
    taxon_match."*Accepted_name_species" AS "Accepted_name_species",
665
    taxon_match."*Accepted_name_family" AS "Accepted_name_family",
666
    taxon_match."*Selected" AS "Selected",
667
    taxon_match."*Source" AS "Source",
668
    taxon_match."*Warnings" AS "Warnings",
669
    taxon_match."*Accepted_name_lsid" AS "Accepted_name_lsid"
670
   FROM taxon_match;
671

    
672

    
673
--
674
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
675
--
676

    
677
CREATE TABLE taxon_match_input__copy_to (
678
    "Name_number" integer,
679
    "Name_submitted" text,
680
    "Overall_score" double precision,
681
    "Name_matched" text,
682
    "Name_matched_rank" text,
683
    "Name_score" double precision,
684
    "Name_matched_author" text,
685
    "Name_matched_url" text,
686
    "Author_matched" text,
687
    "Author_score" double precision,
688
    "Family_matched" text,
689
    "Family_score" double precision,
690
    "Name_matched_accepted_family" text,
691
    "Genus_matched" text,
692
    "Genus_score" double precision,
693
    "Specific_epithet_matched" text,
694
    "Specific_epithet_score" double precision,
695
    "Infraspecific_rank" text,
696
    "Infraspecific_epithet_matched" text,
697
    "Infraspecific_epithet_score" double precision,
698
    "Infraspecific_rank_2" text,
699
    "Infraspecific_epithet_2_matched" text,
700
    "Infraspecific_epithet_2_score" double precision,
701
    "Annotations" text,
702
    "Unmatched_terms" text,
703
    "Taxonomic_status" text,
704
    "Accepted_name" text,
705
    "Accepted_name_author" text,
706
    "Accepted_name_rank" text,
707
    "Accepted_name_url" text,
708
    "Accepted_name_species" text,
709
    "Accepted_name_family" text,
710
    "Selected" text,
711
    "Source" text,
712
    "Warnings" text,
713
    "Accepted_name_lsid" text
714
);
715

    
716

    
717
--
718
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
719
--
720

    
721
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
722
 SELECT taxon_match."*Name_submitted" AS scrubbed_unique_taxon_name,
723
    taxon_match."*Name_matched_rank" AS scrubbed_taxon_rank,
724
    COALESCE(taxon_match."*Name_matched_accepted_family", taxon_match."*Family_matched") AS scrubbed_family,
725
    taxon_match."*Genus_matched" AS scrubbed_genus,
726
    taxon_match."*Specific_epithet_matched" AS scrubbed_specific_epithet,
727
    taxon_match."*Infraspecific_rank" AS scrubbed_infraspecific_rank,
728
    taxon_match."*Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
729
    taxon_match."*Name_matched_author" AS scrubbed_author,
730
    taxon_match."*Name_matched" AS scrubbed_taxon_name_no_author,
731
    (taxon_match."*Name_matched" || COALESCE((' '::text || taxon_match."*Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
732
   FROM taxon_match;
733

    
734

    
735
--
736
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
737
--
738

    
739
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
740
to modify:
741
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
742
SELECT __
743
$$);
744

    
745
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.
746
';
747

    
748

    
749
--
750
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
751
--
752

    
753
CREATE VIEW taxon_scrub AS
754
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
755
    "ValidMatchedTaxon".batch,
756
    "ValidMatchedTaxon".match_num,
757
    "ValidMatchedTaxon"."*Name_number",
758
    "ValidMatchedTaxon"."*Name_submitted",
759
    "ValidMatchedTaxon"."*Overall_score",
760
    "ValidMatchedTaxon"."*Name_matched",
761
    "ValidMatchedTaxon"."*Name_matched_rank",
762
    "ValidMatchedTaxon"."*Name_score",
763
    "ValidMatchedTaxon"."*Name_matched_author",
764
    "ValidMatchedTaxon"."*Name_matched_url",
765
    "ValidMatchedTaxon"."*Author_matched",
766
    "ValidMatchedTaxon"."*Author_score",
767
    "ValidMatchedTaxon"."*Family_matched",
768
    "ValidMatchedTaxon"."*Family_score",
769
    "ValidMatchedTaxon"."*Name_matched_accepted_family",
770
    "ValidMatchedTaxon"."*Genus_matched",
771
    "ValidMatchedTaxon"."*Genus_score",
772
    "ValidMatchedTaxon"."*Specific_epithet_matched",
773
    "ValidMatchedTaxon"."*Specific_epithet_score",
774
    "ValidMatchedTaxon"."*Infraspecific_rank",
775
    "ValidMatchedTaxon"."*Infraspecific_epithet_matched",
776
    "ValidMatchedTaxon"."*Infraspecific_epithet_score",
777
    "ValidMatchedTaxon"."*Infraspecific_rank_2",
778
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_matched",
779
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_score",
780
    "ValidMatchedTaxon"."*Annotations",
781
    "ValidMatchedTaxon"."*Unmatched_terms",
782
    "ValidMatchedTaxon"."*Taxonomic_status",
783
    "ValidMatchedTaxon"."*Accepted_name",
784
    "ValidMatchedTaxon"."*Accepted_name_author",
785
    "ValidMatchedTaxon"."*Accepted_name_rank",
786
    "ValidMatchedTaxon"."*Accepted_name_url",
787
    "ValidMatchedTaxon"."*Accepted_name_species",
788
    "ValidMatchedTaxon"."*Accepted_name_family",
789
    "ValidMatchedTaxon"."*Selected",
790
    "ValidMatchedTaxon"."*Source",
791
    "ValidMatchedTaxon"."*Warnings",
792
    "ValidMatchedTaxon"."*Accepted_name_lsid",
793
    "ValidMatchedTaxon".is_valid_match,
794
    "ValidMatchedTaxon"."taxonomicStatus",
795
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
796
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
797
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
798
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
799
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
800
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
801
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
802
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
803
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
804
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
805
        CASE
806
            WHEN ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'family'::text) THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, "ValidMatchedTaxon"."*Unmatched_terms")
807
            WHEN ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, "ValidMatchedTaxon"."*Unmatched_terms")
808
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
809
        END AS scrubbed_morphospecies_binomial
810
   FROM ("ValidMatchedTaxon"
811
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
812

    
813

    
814
--
815
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
816
--
817

    
818
COMMENT ON VIEW taxon_scrub IS '
819
to modify:
820
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
821
SELECT __
822
$$);
823
';
824

    
825

    
826
--
827
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
828
--
829

    
830
ALTER TABLE ONLY batch_download_settings
831
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
832

    
833

    
834
--
835
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
836
--
837

    
838
ALTER TABLE ONLY batch
839
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
840

    
841

    
842
--
843
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
844
--
845

    
846
ALTER TABLE ONLY batch
847
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
848

    
849

    
850
--
851
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
852
--
853

    
854
ALTER TABLE ONLY client_version
855
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
856

    
857

    
858
--
859
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
860
--
861

    
862
ALTER TABLE ONLY taxon_match
863
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
864

    
865
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
866

    
867

    
868
--
869
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
870
--
871

    
872
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
873

    
874

    
875
--
876
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
877
--
878

    
879
CREATE INDEX taxon_best_match__valid_match ON taxon_match USING btree ("*Name_submitted") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
880

    
881

    
882
--
883
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
884
--
885

    
886
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
887

    
888

    
889
--
890
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
891
--
892

    
893
CREATE UNIQUE INDEX taxon_match__one_selected_match ON taxon_match USING btree (batch, "*Name_number") WHERE ("*Selected" = 'true'::text);
894

    
895

    
896
--
897
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
898
--
899

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

    
902

    
903
--
904
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
905
--
906

    
907
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
908

    
909

    
910
--
911
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
912
--
913

    
914
CREATE TRIGGER taxon_match__fill BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill();
915

    
916

    
917
--
918
-- Name: taxon_match__fill_derived; Type: TRIGGER; Schema: TNRS; Owner: -
919
--
920

    
921
CREATE TRIGGER taxon_match__fill_derived BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill_derived();
922

    
923

    
924
--
925
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
926
--
927

    
928
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
929

    
930

    
931
--
932
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
933
--
934

    
935
CREATE TRIGGER taxon_match_input__copy_to__insert BEFORE INSERT ON taxon_match_input__copy_to FOR EACH ROW EXECUTE PROCEDURE taxon_match_input__copy_to__insert();
936

    
937

    
938
--
939
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
940
--
941

    
942
ALTER TABLE ONLY batch
943
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
944

    
945

    
946
--
947
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
948
--
949

    
950
ALTER TABLE ONLY batch_download_settings
951
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
952

    
953

    
954
--
955
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
956
--
957

    
958
ALTER TABLE ONLY taxon_match
959
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
960

    
961

    
962
--
963
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
964
--
965

    
966
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
967
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
968
GRANT ALL ON SCHEMA "TNRS" TO bien;
969
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
970

    
971

    
972
--
973
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
974
--
975

    
976
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
977
REVOKE ALL ON TABLE taxon_match FROM bien;
978
GRANT ALL ON TABLE taxon_match TO bien;
979
GRANT SELECT ON TABLE taxon_match TO bien_read;
980

    
981

    
982
--
983
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
984
--
985

    
986
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
987
REVOKE ALL ON TABLE taxon_best_match FROM bien;
988
GRANT ALL ON TABLE taxon_best_match TO bien;
989
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
990

    
991

    
992
--
993
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
994
--
995

    
996
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
997
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
998
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
999
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
1000

    
1001

    
1002
--
1003
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1004
--
1005

    
1006
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
1007
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
1008
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
1009
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
1010

    
1011

    
1012
--
1013
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
1014
--
1015

    
1016
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
1017
REVOKE ALL ON TABLE taxon_match_input FROM bien;
1018
GRANT ALL ON TABLE taxon_match_input TO bien;
1019
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
1020

    
1021

    
1022
--
1023
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
1024
--
1025

    
1026
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
1027
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
1028
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1029
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1030

    
1031

    
1032
--
1033
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1034
--
1035

    
1036
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1037
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1038
GRANT ALL ON TABLE taxon_scrub TO bien;
1039
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1040

    
1041

    
1042
--
1043
-- PostgreSQL database dump complete
1044
--
1045

    
(7-7/9)