Skip to content

Commit b65f025

Browse files
committed
feat: improve taxons search (unaccent, better display)
Resolve #532.
1 parent 3978263 commit b65f025

File tree

6 files changed

+153
-42
lines changed

6 files changed

+153
-42
lines changed

atlas/atlasAPI.py

+1-1
Original file line numberDiff line numberDiff line change
@@ -20,7 +20,7 @@ def searchTaxonAPI():
2020
session = db.session
2121
search = request.args.get("search", "")
2222
limit = request.args.get("limit", 50)
23-
results = vmSearchTaxonRepository.listeTaxonsSearch(session, search, limit)
23+
results = vmSearchTaxonRepository.searchTaxons(session, search, limit)
2424
session.close()
2525
return jsonify(results)
2626

atlas/modeles/entities/vmSearchTaxon.py

+1
Original file line numberDiff line numberDiff line change
@@ -14,6 +14,7 @@ class VmSearchTaxon(Base):
1414
metadata,
1515
Column("cd_ref", Integer, primary_key=True, unique=True),
1616
Column("cd_nom", Integer),
17+
Column("display_name", String),
1718
Column("search_name", String),
1819
schema="atlas",
1920
autoload=True,

atlas/modeles/repositories/vmSearchTaxonRepository.py

+13-13
Original file line numberDiff line numberDiff line change
@@ -19,7 +19,7 @@ def listeTaxons(session):
1919
return taxonList
2020

2121

22-
def listeTaxonsSearch(session, search, limit=50):
22+
def searchTaxons(session, search, limit=50):
2323
"""
2424
Recherche dans la VmSearchTaxon en ilike
2525
Utilisé pour l'autocomplétion de la recherche de taxon
@@ -34,20 +34,20 @@ def listeTaxonsSearch(session, search, limit=50):
3434
label = search_name
3535
value = cd_ref
3636
"""
37-
38-
req = session.query(
39-
VmSearchTaxon.search_name,
40-
VmSearchTaxon.cd_ref,
41-
func.similarity(VmSearchTaxon.search_name, search).label("idx_trgm"),
42-
).distinct()
43-
44-
search = search.replace(" ", "%")
45-
req = (
46-
req.filter(VmSearchTaxon.search_name.ilike("%" + search + "%"))
37+
like_search = "%" + search.replace(" ", "%") + "%"
38+
39+
query = (
40+
session.query(
41+
VmSearchTaxon.display_name,
42+
VmSearchTaxon.cd_ref,
43+
func.similarity(VmSearchTaxon.search_name, search).label("idx_trgm"),
44+
)
45+
.distinct()
46+
.filter(func.unaccent(VmSearchTaxon.search_name).ilike(func.unaccent(like_search)))
4747
.order_by(desc("idx_trgm"))
4848
.order_by(VmSearchTaxon.cd_ref == VmSearchTaxon.cd_nom)
4949
.limit(limit)
5050
)
51-
data = req.all()
51+
results = query.all()
5252

53-
return [{"label": d[0], "value": d[1]} for d in data]
53+
return [{"label": r[0], "value": r[1]} for r in results]
+56-28
Original file line numberDiff line numberDiff line change
@@ -1,34 +1,62 @@
1-
-- Taxons observés et de tous leurs synonymes (utilisés pour la recherche d'une espèce)
1+
CREATE MATERIALIZED VIEW atlas.vm_search_taxon AS
2+
WITH verna_names AS (
3+
SELECT DISTINCT
4+
cd_nom,
5+
lb_nom,
6+
cd_ref,
7+
STRING_TO_TABLE(nom_vern, ', ') AS nom_vern
8+
FROM atlas.vm_taxref
9+
WHERE nom_vern IS NOT NULL
10+
AND cd_nom = cd_ref
11+
AND nom_vern <> lb_nom
12+
),
13+
names AS (
14+
-- Chosen scinames
15+
SELECT
16+
cd_nom,
17+
cd_ref,
18+
lb_nom AS search_name,
19+
CONCAT('<b>', REPLACE(nom_complet_html, lb_auteur, ''), '</b> ', lb_auteur) AS display_name
20+
FROM atlas.vm_taxref
21+
WHERE cd_nom = cd_ref
222

3-
CREATE MATERIALIZED VIEW atlas.vm_search_taxon AS
4-
SELECT row_number() OVER (ORDER BY t.cd_nom,t.cd_ref,t.search_name)::integer AS fid,
5-
t.cd_nom,
6-
t.cd_ref,
7-
t.search_name,
8-
t.nom_valide,
9-
t.lb_nom
10-
FROM (
11-
SELECT t_1.cd_nom,
12-
t_1.cd_ref,
13-
concat(t_1.lb_nom, ' = <i> ', t_1.nom_valide, '</i>') AS search_name,
14-
t_1.nom_valide,
15-
t_1.lb_nom
16-
FROM atlas.vm_taxref t_1
23+
UNION
1724

18-
UNION
19-
SELECT t_1.cd_nom,
20-
t_1.cd_ref,
21-
concat(t_1.nom_vern, ' = <i> ', t_1.nom_valide, '</i>' ) AS search_name,
22-
t_1.nom_valide,
23-
t_1.lb_nom
24-
FROM atlas.vm_taxref t_1
25-
WHERE t_1.nom_vern IS NOT NULL AND t_1.cd_nom = t_1.cd_ref
26-
) t
27-
JOIN atlas.vm_taxons taxons ON taxons.cd_ref = t.cd_ref;
25+
-- Synonym scinames
26+
SELECT
27+
t1.cd_nom,
28+
t1.cd_ref,
29+
t1.lb_nom AS search_name,
30+
CONCAT(REPLACE(t1.nom_complet_html, t1.lb_auteur, ''), ' = <b> ', REPLACE(t2.nom_complet_html, t2.lb_auteur, ''), '</b> ', t2.lb_auteur) AS display_name
31+
FROM atlas.vm_taxref AS t1
32+
JOIN atlas.vm_taxref AS t2
33+
ON t1.cd_ref = t2.cd_nom
34+
WHERE t1.cd_nom <> t1.cd_ref
35+
36+
UNION
37+
38+
-- Vernacular names
39+
SELECT
40+
v.cd_nom,
41+
v.cd_ref,
42+
v.nom_vern AS search_name,
43+
CONCAT(v.nom_vern, ' = <b> ', REPLACE(t.nom_complet_html, t.lb_auteur, ''), '</b> ', t.lb_auteur) AS display_name
44+
FROM verna_names AS v
45+
JOIN atlas.vm_taxref AS t
46+
ON t.cd_nom = v.cd_ref
47+
WHERE v.nom_vern <> v.lb_nom
48+
)
49+
SELECT ROW_NUMBER() OVER (ORDER BY n.cd_nom, n.cd_ref, n.search_name)::integer AS fid,
50+
n.cd_nom,
51+
n.cd_ref,
52+
n.search_name,
53+
n.display_name
54+
FROM atlas.vm_taxons AS t
55+
JOIN names AS n
56+
ON t.cd_ref = n.cd_ref ;
2857

2958
CREATE UNIQUE INDEX ON atlas.vm_search_taxon(fid);
3059
CREATE INDEX ON atlas.vm_search_taxon(cd_nom);
31-
create INDEX ON atlas.vm_search_taxon(cd_ref);
32-
60+
CREATE INDEX ON atlas.vm_search_taxon(cd_ref);
3361
CREATE INDEX trgm_idx ON atlas.vm_search_taxon USING GIST (search_name gist_trgm_ops);
34-
CREATE UNIQUE INDEX ON atlas.vm_search_taxon (cd_nom, search_name);
62+
CREATE UNIQUE INDEX ON atlas.vm_search_taxon (cd_nom, search_name);

data/update/update_1.6.1to1.6.2.sql

+69
Original file line numberDiff line numberDiff line change
@@ -43,3 +43,72 @@ CREATE INDEX ON atlas.vm_observations_mailles
4343

4444
CREATE INDEX ON atlas.vm_observations_mailles
4545
USING btree (id_maille, cd_ref);
46+
47+
48+
-- ISSUE #531 & #532
49+
CREATE EXTENSION IF NOT EXISTS unaccent SCHEMA "public";
50+
51+
-- ISSUE #532
52+
DROP MATERIALIZED VIEW IF EXISTS atlas.vm_search_taxon ;
53+
CREATE MATERIALIZED VIEW atlas.vm_search_taxon AS
54+
WITH verna_names AS (
55+
SELECT DISTINCT
56+
cd_nom,
57+
lb_nom,
58+
cd_ref,
59+
STRING_TO_TABLE(nom_vern, ', ') AS nom_vern
60+
FROM atlas.vm_taxref
61+
WHERE nom_vern IS NOT NULL
62+
AND cd_nom = cd_ref
63+
AND nom_vern <> lb_nom
64+
),
65+
names AS (
66+
-- Chosen scinames
67+
SELECT
68+
cd_nom,
69+
cd_ref,
70+
lb_nom AS search_name,
71+
CONCAT('<b>', REPLACE(nom_complet_html, lb_auteur, ''), '</b> ', lb_auteur) AS display_name
72+
FROM atlas.vm_taxref
73+
WHERE cd_nom = cd_ref
74+
75+
UNION
76+
77+
-- Synonym scinames
78+
SELECT
79+
t1.cd_nom,
80+
t1.cd_ref,
81+
t1.lb_nom AS search_name,
82+
CONCAT(REPLACE(t1.nom_complet_html, t1.lb_auteur, ''), ' = <b> ', REPLACE(t2.nom_complet_html, t2.lb_auteur, ''), '</b> ', t2.lb_auteur) AS display_name
83+
FROM atlas.vm_taxref AS t1
84+
JOIN atlas.vm_taxref AS t2
85+
ON t1.cd_ref = t2.cd_nom
86+
WHERE t1.cd_nom <> t1.cd_ref
87+
88+
UNION
89+
90+
-- Vernacular names
91+
SELECT
92+
v.cd_nom,
93+
v.cd_ref,
94+
v.nom_vern AS search_name,
95+
CONCAT(v.nom_vern, ' = <b> ', REPLACE(t.nom_complet_html, t.lb_auteur, ''), '</b> ', t.lb_auteur) AS display_name
96+
FROM verna_names AS v
97+
JOIN atlas.vm_taxref AS t
98+
ON t.cd_nom = v.cd_ref
99+
WHERE v.nom_vern <> v.lb_nom
100+
)
101+
SELECT ROW_NUMBER() OVER (ORDER BY n.cd_nom, n.cd_ref, n.search_name)::integer AS fid,
102+
n.cd_nom,
103+
n.cd_ref,
104+
n.search_name,
105+
n.display_name
106+
FROM atlas.vm_taxons AS t
107+
JOIN names AS n
108+
ON t.cd_ref = n.cd_ref ;
109+
110+
CREATE UNIQUE INDEX ON atlas.vm_search_taxon(fid);
111+
CREATE INDEX ON atlas.vm_search_taxon(cd_nom);
112+
CREATE INDEX ON atlas.vm_search_taxon(cd_ref);
113+
CREATE INDEX trgm_idx ON atlas.vm_search_taxon USING GIST (search_name gist_trgm_ops);
114+
CREATE UNIQUE INDEX ON atlas.vm_search_taxon (cd_nom, search_name);

docs/changelog.rst

+13
Original file line numberDiff line numberDiff line change
@@ -2,6 +2,19 @@
22
CHANGELOG
33
=========
44

5+
[Unreleased]
6+
------------------
7+
8+
⚠️ **Notes de version**
9+
10+
Si vous mettez à jour GeoNature-atlas :
11+
12+
- Exécutez le script SQL de mise à jour de la BDD : https://github.com/PnX-SI/GeoNature-atlas/blob/master/data/update/update_1.6.1to1.6.2.sql
13+
- Donner les droits à l'utilisateur en lecture seule de l'Atlas (habituellement geonatatlas) :
14+
::
15+
GRANT SELECT ON TABLE atlas.vm_search_taxon TO geonatatlas;
16+
17+
518
1.6.1 (2023-10-16)
619
------------------
720

0 commit comments

Comments
 (0)