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
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
344
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
345

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

    
349

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

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

    
398

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

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

    
410

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

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

    
464

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

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

    
476

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

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

    
527

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

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

    
536

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

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

    
548

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

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

    
570

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

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

    
579

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

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

    
591

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

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

    
600

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

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

    
609

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

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

    
618

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

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

    
627

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

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

    
671

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

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

    
715

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

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

    
733

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

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

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

    
747

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

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

    
812

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

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

    
824

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

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

    
832

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

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

    
840

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

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

    
848

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

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

    
856

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

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

    
864
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
865

    
866

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

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

    
873

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

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

    
880

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

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

    
887

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

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

    
894

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

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

    
901

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

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

    
908

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

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

    
915

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

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

    
922

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

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

    
929

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

    
934
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();
935

    
936

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

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

    
944

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

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

    
952

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

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

    
960

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

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

    
970

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

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

    
980

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

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

    
990

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

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

    
1000

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

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

    
1010

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

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

    
1020

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

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

    
1030

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

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

    
1040

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

    
(7-7/9)