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_name_species" text,
46
  "Accepted_name_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
  "Is_plant" boolean,
54
  CONSTRAINT tnrs_pkey PRIMARY KEY ("Name_submitted" )
55
)
56
WITH (
57
  OIDS=FALSE
58
);
59

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

    
66
CREATE OR REPLACE FUNCTION tnrs_populate_fields()
67
  RETURNS trigger AS
68
$BODY$
69
DECLARE
70
    "Specific_epithet_is_plant" boolean :=
71
        (CASE
72
        WHEN   new."Infraspecific_epithet_matched"   IS NOT NULL
73
            OR new."Infraspecific_epithet_2_matched" IS NOT NULL
74
            OR new."Specific_epithet_score"::double precision >= 0.9 -- fuzzy match
75
            THEN true
76
        ELSE NULL -- ambiguous
77
        END);
78
BEGIN
79
    new."Accepted_scientific_name" = NULLIF(concat_ws(' '
80
        , NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'), new."Accepted_name")
81
        , new."Accepted_name"
82
        , new."Accepted_name_author"
83
    ), '');
84
    new."Max_score" = GREATEST(
85
          new."Overall_score"::double precision
86
        , new."Family_score"::double precision
87
        , new."Genus_score"::double precision
88
        , new."Specific_epithet_score"::double precision
89
    );
90
    new."Is_plant" = (CASE
91
        WHEN new."Family_matched" IS NOT NULL THEN true
92
        ELSE -- Family_matched IS NULL
93
            (CASE
94
            WHEN new."Genus_score"::double precision =  1    -- exact match
95
                THEN "Specific_epithet_is_plant"
96
            WHEN new."Genus_score"::double precision >= 0.85 -- fuzzy match
97
                THEN "Specific_epithet_is_plant"
98
            ELSE NULL -- ambiguous
99
            END)
100
        END);
101
    
102
    RETURN new;
103
END;
104
$BODY$
105
  LANGUAGE plpgsql VOLATILE
106
  COST 100;
107

    
108
CREATE TRIGGER tnrs_populate_fields
109
  BEFORE INSERT OR UPDATE
110
  ON tnrs
111
  FOR EACH ROW
112
  EXECUTE PROCEDURE tnrs_populate_fields();
113

    
114

    
115
CREATE OR REPLACE VIEW "MatchedTaxon" AS
116
SELECT
117
  "Time_submitted" AS "*Name_matched.Time_submitted"
118
, "Name_submitted" AS "concatenatedScientificName"
119
, "Name_matched" AS "matchedTaxonName"
120
, "Name_matched_rank" AS "matchedTaxonRank"
121
, "Name_score" AS "*Name_matched.Name_score"
122
, "Name_matched_author" AS "matchedScientificNameAuthorship"
123
, "Name_matched_url" AS "matchedScientificNameID"
124
, "Author_score" AS "*Name_matched.Author_score"
125
, "Family_score" AS "matchedFamilyConfidence_fraction"
126
, COALESCE("Name_matched_accepted_family", "Accepted_name_family") AS "matchedFamily"
127
, "Genus_matched" AS "matchedGenus"
128
, "Genus_score" AS "matchedGenusConfidence_fraction"
129
, "Specific_epithet_matched" AS "matchedSpecificEpithet"
130
, "Specific_epithet_score" AS "matchedSpeciesConfidence_fraction"
131
, "Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet"
132
, "Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score"
133
, "Annotations" AS "identificationQualifier"
134
, "Unmatched_terms" AS "morphospeciesSuffix"
135
, "Taxonomic_status" AS "taxonomicStatus"
136
, "Accepted_name" AS "acceptedTaxonName"
137
, "Accepted_name_author" AS "acceptedScientificNameAuthorship"
138
, "Accepted_name_rank" AS "acceptedTaxonRank"
139
, "Accepted_name_url" AS "acceptedScientificNameID"
140
, "Accepted_name_species" AS "*Name_matched.Accepted_name_species"
141
, "Accepted_name_family" AS "acceptedFamily"
142
, "Selected" AS "*Name_matched.Selected"
143
, "Source" AS "*Name_matched.Source"
144
, "Warnings" AS "*Name_matched.Warnings"
145
, "Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid"
146
, "Accepted_scientific_name" AS "acceptedScientificName"
147
, "Max_score" AS "matchedTaxonConfidence_fraction"
148
FROM tnrs
149
;
150

    
151
CREATE OR REPLACE VIEW "ValidMatchedTaxon" AS
152
SELECT *
153
FROM "MatchedTaxon"
154
WHERE score_ok("matchedTaxonConfidence_fraction")
155
;
156

    
157
CREATE OR REPLACE VIEW "AcceptedTaxon" AS
158
SELECT
159
  "Time_submitted" AS "*Accepted_name.Time_submitted"
160
, "Name_submitted" AS "acceptedScientificName"
161
, "Genus_matched" AS "acceptedGenus"
162
, "Specific_epithet_matched" AS "acceptedSpecificEpithet"
163
, "Infraspecific_epithet_matched" AS "acceptedInfraspecificEpithet"
164
, "Annotations" AS "*Accepted_name.Annotations"
165
, "Taxonomic_status" AS "acceptedTaxonomicStatus"
166
, "Selected" AS "*Accepted_name.Selected"
167
, "Source" AS "*Accepted_name.Source"
168
, "Warnings" AS "*Accepted_name.Warnings"
169
, "Accepted_name_lsid" AS "*Accepted_name.Accepted_name_lsid"
170
FROM tnrs
171
;
172

    
173
CREATE OR REPLACE VIEW "ScrubbedTaxon" AS
174
SELECT *
175
FROM "ValidMatchedTaxon"
176
NATURAL LEFT JOIN "AcceptedTaxon"
177
;
(4-4/4)