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", ' '::text)
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
whenever columns are renamed:
331
SELECT util.derived_cols_sync(''"TNRS".taxon_match'');
332

    
333
to remove columns or add columns at the end:
334
$ rm=1 inputs/.TNRS/data.sql.run
335
$ make schemas/remake
336

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

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

    
350
to add a constraint: runtime: 3 min ("173620 ms")
351
';
352

    
353

    
354
--
355
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
356
--
357

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

    
402

    
403
--
404
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
405
--
406

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

    
414

    
415
--
416
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
417
--
418

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

    
468

    
469
--
470
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
471
--
472

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

    
480

    
481
--
482
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
483
--
484

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

    
531

    
532
--
533
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
534
--
535

    
536
COMMENT ON VIEW "ValidMatchedTaxon" IS '
537
to update, use * as the column list
538
';
539

    
540

    
541
--
542
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
543
--
544

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

    
552

    
553
--
554
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
555
--
556

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

    
574

    
575
--
576
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
577
--
578

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

    
583

    
584
--
585
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
586
--
587

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

    
595

    
596
--
597
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
598
--
599

    
600
COMMENT ON TABLE client_version IS '
601
contains svn revisions
602
';
603

    
604

    
605
--
606
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
607
--
608

    
609
COMMENT ON COLUMN client_version.global_rev IS '
610
from `svn info .` > Last Changed Rev
611
';
612

    
613

    
614
--
615
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
616
--
617

    
618
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
619
from `svn info lib/tnrs.py` > Last Changed Rev
620
';
621

    
622

    
623
--
624
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
625
--
626

    
627
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
628
from `svn info bin/tnrs_db` > Last Changed Rev
629
';
630

    
631

    
632
--
633
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
634
--
635

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

    
675

    
676
--
677
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
678
--
679

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

    
719

    
720
--
721
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
722
--
723

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

    
737

    
738
--
739
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
740
--
741

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

    
748
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.
749
';
750

    
751

    
752
--
753
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
754
--
755

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

    
816

    
817
--
818
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
819
--
820

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

    
828

    
829
--
830
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
831
--
832

    
833
ALTER TABLE ONLY batch_download_settings
834
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
835

    
836

    
837
--
838
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
839
--
840

    
841
ALTER TABLE ONLY batch
842
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
843

    
844

    
845
--
846
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
847
--
848

    
849
ALTER TABLE ONLY batch
850
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
851

    
852

    
853
--
854
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
855
--
856

    
857
ALTER TABLE ONLY client_version
858
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
859

    
860

    
861
--
862
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
863
--
864

    
865
ALTER TABLE ONLY taxon_match
866
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
867

    
868
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
869

    
870

    
871
--
872
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
873
--
874

    
875
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
876

    
877

    
878
--
879
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
880
--
881

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

    
884

    
885
--
886
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
887
--
888

    
889
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
890

    
891

    
892
--
893
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
894
--
895

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

    
898

    
899
--
900
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
901
--
902

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

    
905

    
906
--
907
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
908
--
909

    
910
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
911

    
912

    
913
--
914
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
915
--
916

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

    
919

    
920
--
921
-- Name: taxon_match__fill_derived; Type: TRIGGER; Schema: TNRS; Owner: -
922
--
923

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

    
926

    
927
--
928
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
929
--
930

    
931
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
932

    
933

    
934
--
935
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
936
--
937

    
938
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();
939

    
940

    
941
--
942
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
943
--
944

    
945
ALTER TABLE ONLY batch
946
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
947

    
948

    
949
--
950
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
951
--
952

    
953
ALTER TABLE ONLY batch_download_settings
954
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
955

    
956

    
957
--
958
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
959
--
960

    
961
ALTER TABLE ONLY taxon_match
962
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
963

    
964

    
965
--
966
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
967
--
968

    
969
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
970
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
971
GRANT ALL ON SCHEMA "TNRS" TO bien;
972
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
973

    
974

    
975
--
976
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
977
--
978

    
979
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
980
REVOKE ALL ON TABLE taxon_match FROM bien;
981
GRANT ALL ON TABLE taxon_match TO bien;
982
GRANT SELECT ON TABLE taxon_match TO bien_read;
983

    
984

    
985
--
986
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
987
--
988

    
989
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
990
REVOKE ALL ON TABLE taxon_best_match FROM bien;
991
GRANT ALL ON TABLE taxon_best_match TO bien;
992
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
993

    
994

    
995
--
996
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
997
--
998

    
999
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
1000
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
1001
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
1002
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
1003

    
1004

    
1005
--
1006
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1007
--
1008

    
1009
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
1010
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
1011
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
1012
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
1013

    
1014

    
1015
--
1016
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
1017
--
1018

    
1019
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
1020
REVOKE ALL ON TABLE taxon_match_input FROM bien;
1021
GRANT ALL ON TABLE taxon_match_input TO bien;
1022
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
1023

    
1024

    
1025
--
1026
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
1027
--
1028

    
1029
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
1030
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
1031
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1032
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1033

    
1034

    
1035
--
1036
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1037
--
1038

    
1039
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1040
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1041
GRANT ALL ON TABLE taxon_scrub TO bien;
1042
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1043

    
1044

    
1045
--
1046
-- PostgreSQL database dump complete
1047
--
1048

    
(7-7/9)