Project

General

Profile

1
CREATE OR REPLACE FUNCTION score_ok(score double precision)
2
  RETURNS boolean AS
3
$BODY$
4
SELECT $1 >= 0.8
5
$BODY$
6
  LANGUAGE sql VOLATILE
7
  COST 100;
8

    
9
/* IMPORTANT: when changing this table's schema, you must regenerate data.sql:
10
$ <this_file>/../test_taxonomic_names/test_scrub
11
*/
12
CREATE TABLE tnrs
13
(
14
  "Time_submitted" timestamp with time zone DEFAULT now(),
15
  "Name_number" text,
16
  "Name_submitted" text NOT NULL,
17
  "Overall_score" text,
18
  "Name_matched" text,
19
  "Name_matched_rank" text,
20
  "Name_score" text,
21
  "Name_matched_author" text,
22
  "Name_matched_url" text,
23
  "Author_matched" text,
24
  "Author_score" text,
25
  "Family_matched" text,
26
  "Family_score" text,
27
  "Name_matched_accepted_family" text,
28
  "Genus_matched" text,
29
  "Genus_score" text,
30
  "Specific_epithet_matched" text,
31
  "Specific_epithet_score" text,
32
  "Infraspecific_rank" text,
33
  "Infraspecific_epithet_matched" text,
34
  "Infraspecific_epithet_score" text,
35
  "Infraspecific_rank_2" text,
36
  "Infraspecific_epithet_2_matched" text,
37
  "Infraspecific_epithet_2_score" text,
38
  "Annotations" text,
39
  "Unmatched_terms" text,
40
  "Taxonomic_status" text,
41
  "Accepted_name" text,
42
  "Accepted_name_author" text,
43
  "Accepted_name_rank" text,
44
  "Accepted_name_url" text,
45
  "Accepted_species" text,
46
  "Accepted_family" text,
47
  "Selected" text,
48
  "Source" text,
49
  "Warnings" text,
50
  "Accepted_name_lsid" text,
51
  "Accepted_scientific_name" text,
52
  "Max_score" double precision,
53
  CONSTRAINT tnrs_pkey PRIMARY KEY ("Name_submitted" )
54
)
55
WITH (
56
  OIDS=FALSE
57
);
58

    
59
CREATE UNIQUE INDEX tnrs_score_ok
60
  ON tnrs
61
  USING btree
62
  ("Name_submitted" )
63
  WHERE score_ok("Max_score");
64

    
65
CREATE OR REPLACE FUNCTION tnrs_populate_fields()
66
  RETURNS trigger AS
67
$BODY$
68
BEGIN
69
    new."Accepted_scientific_name" = NULLIF(concat_ws(' '
70
        , NULLIF(NULLIF(new."Accepted_family", 'Unknown'), new."Accepted_name")
71
        , new."Accepted_name"
72
        , new."Accepted_name_author"
73
    ), '');
74
    new."Max_score" = GREATEST(
75
          new."Overall_score"::double precision
76
        , new."Family_score"::double precision
77
        , new."Genus_score"::double precision
78
        , new."Specific_epithet_score"::double precision
79
    );
80
    
81
    RETURN new;
82
END;
83
$BODY$
84
  LANGUAGE plpgsql VOLATILE
85
  COST 100;
86

    
87
CREATE TRIGGER tnrs_populate_fields
88
  BEFORE INSERT OR UPDATE
89
  ON tnrs
90
  FOR EACH ROW
91
  EXECUTE PROCEDURE tnrs_populate_fields();
92

    
93

    
94
CREATE OR REPLACE VIEW "MatchedTaxon" AS
95
SELECT
96
  "Time_submitted" AS "*Name_matched.Time_submitted"
97
, "Name_submitted" AS "concatenatedScientificName"
98
, "Name_matched" AS "matchedTaxonName"
99
, "Name_matched_rank" AS "matchedTaxonRank"
100
, "Name_score" AS "*Name_matched.Name_score"
101
, "Name_matched_author" AS "matchedScientificNameAuthorship"
102
, "Name_matched_url" AS "matchedScientificNameID"
103
, "Author_score" AS "*Name_matched.Author_score"
104
, "Family_score" AS "matchedFamilyConfidence_fraction"
105
, COALESCE("Name_matched_accepted_family", "Accepted_family") AS "matchedFamily"
106
, "Genus_matched" AS "matchedGenus"
107
, "Genus_score" AS "matchedGenusConfidence_fraction"
108
, "Specific_epithet_matched" AS "matchedSpecificEpithet"
109
, "Specific_epithet_score" AS "matchedSpeciesConfidence_fraction"
110
, "Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet"
111
, "Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score"
112
, "Annotations" AS "identificationQualifier"
113
, "Unmatched_terms" AS "morphospeciesSuffix"
114
, "Taxonomic_status" AS "taxonomicStatus"
115
, "Accepted_name" AS "acceptedTaxonName"
116
, "Accepted_name_author" AS "acceptedScientificNameAuthorship"
117
, "Accepted_name_rank" AS "acceptedTaxonRank"
118
, "Accepted_name_url" AS "acceptedScientificNameID"
119
, "Accepted_species" AS "*Name_matched.Accepted_species"
120
, "Accepted_family" AS "acceptedFamily"
121
, "Selected" AS "*Name_matched.Selected"
122
, "Source" AS "*Name_matched.Source"
123
, "Warnings" AS "*Name_matched.Warnings"
124
, "Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid"
125
, "Accepted_scientific_name" AS "acceptedScientificName"
126
, "Max_score" AS "matchedTaxonConfidence_fraction"
127
FROM tnrs
128
;
129

    
130
CREATE OR REPLACE VIEW "ValidMatchedTaxon" AS
131
SELECT *
132
FROM "MatchedTaxon"
133
WHERE score_ok("matchedTaxonConfidence_fraction")
134
;
135

    
136
CREATE OR REPLACE VIEW "AcceptedTaxon" AS
137
SELECT
138
  "Time_submitted" AS "*Accepted_name.Time_submitted"
139
, "Name_submitted" AS "acceptedScientificName"
140
, "Genus_matched" AS "acceptedGenus"
141
, "Specific_epithet_matched" AS "acceptedSpecificEpithet"
142
, "Infraspecific_epithet_matched" AS "acceptedInfraspecificEpithet"
143
, "Annotations" AS "*Accepted_name.Annotations"
144
, "Taxonomic_status" AS "acceptedTaxonomicStatus"
145
, "Selected" AS "*Accepted_name.Selected"
146
, "Source" AS "*Accepted_name.Source"
147
, "Warnings" AS "*Accepted_name.Warnings"
148
, "Accepted_name_lsid" AS "*Accepted_name.Accepted_name_lsid"
149
FROM tnrs
150
;
151

    
152
CREATE OR REPLACE VIEW "ScrubbedTaxon" AS
153
SELECT *
154
FROM "ValidMatchedTaxon"
155
NATURAL LEFT JOIN "AcceptedTaxon"
156
;
(4-4/4)