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 NOT NULL DEFAULT now(),
15
  "Name_number" integer NOT NULL,
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 ("Time_submitted" , "Name_number" ),
55
  CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted" )
56
)
57
WITH (
58
  OIDS=FALSE
59
);
60

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

    
67
/* IMPORTANT: when changing this function, you must regenerate the derived cols:
68
UPDATE tnrs SET "Name_submitted" = "Name_submitted"
69
runtime: 17 min ("4992166 rows affected, 1019907 ms execution time")
70
*/
71
CREATE OR REPLACE FUNCTION tnrs_populate_fields()
72
  RETURNS trigger AS
73
$BODY$
74
DECLARE
75
    "Specific_epithet_is_plant" boolean :=
76
        (CASE
77
        WHEN   new."Infraspecific_epithet_matched"   IS NOT NULL
78
            OR new."Infraspecific_epithet_2_matched" IS NOT NULL
79
            OR new."Specific_epithet_score"::double precision >= 0.9 -- fuzzy match
80
            THEN true
81
        ELSE NULL -- ambiguous
82
        END);
83
BEGIN
84
    new."Accepted_scientific_name" = NULLIF(concat_ws(' '
85
        , NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'), new."Accepted_name")
86
        , new."Accepted_name"
87
        , new."Accepted_name_author"
88
    ), '');
89
    new."Max_score" = GREATEST(
90
          new."Overall_score"::double precision
91
        , new."Family_score"::double precision
92
        , new."Genus_score"::double precision
93
        , new."Specific_epithet_score"::double precision
94
    );
95
    new."Is_plant" = (CASE
96
        WHEN new."Family_score"::double precision = 1 THEN true -- exact match
97
        ELSE -- Family_matched IS NULL
98
            (CASE
99
            WHEN new."Genus_score"::double precision =  1    -- exact match
100
                THEN "Specific_epithet_is_plant"
101
            WHEN new."Genus_score"::double precision >= 0.85 -- fuzzy match
102
                THEN "Specific_epithet_is_plant"
103
            ELSE NULL -- ambiguous
104
            END)
105
        END);
106
    
107
    RETURN new;
108
END;
109
$BODY$
110
  LANGUAGE plpgsql VOLATILE
111
  COST 100;
112

    
113
CREATE TRIGGER tnrs_populate_fields
114
  BEFORE INSERT OR UPDATE
115
  ON tnrs
116
  FOR EACH ROW
117
  EXECUTE PROCEDURE tnrs_populate_fields();
118

    
119

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

    
156
CREATE OR REPLACE VIEW "ValidMatchedTaxon" AS
157
SELECT *
158
FROM "MatchedTaxon"
159
WHERE score_ok("matchedTaxonConfidence_fraction")
160
;
161

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

    
178
CREATE OR REPLACE VIEW "ScrubbedTaxon" AS
179
SELECT *
180
FROM "ValidMatchedTaxon"
181
NATURAL LEFT JOIN "AcceptedTaxon"
182
;
(4-4/4)