Skip to content
Snippets Groups Projects
Commit 31139484 authored by Martin Mareš's avatar Martin Mareš
Browse files

DB: Index na case-insensitive accent-insensitive hledání ve jménech míst

parent ee3c84d2
No related branches found
No related tags found
1 merge request!86Registrace
-- CREATE ROLE mo_osmo LOGIN PASSWORD 'pass';
-- CREATE DATABASE mo_osmo WITH OWNER=mo_osmo;
-- GRANT mo_osmo TO some_admin;
-- CREATE EXTENSION unaccent;
SET ROLE mo_osmo;
-- Funkce pro odakcentování textu pomocí extension unaccent.
-- Je immutable, takže se dá používat i v indexech.
-- Zdroj: http://stackoverflow.com/questions/11005036/does-postgresql-support-accent-insensitive-collations
CREATE OR REPLACE FUNCTION f_unaccent(text)
RETURNS text AS
$func$
SELECT unaccent('unaccent', $1)
$func$ LANGUAGE sql IMMUTABLE SET search_path = public, pg_temp;
-- Uživatelský účet
CREATE TABLE users (
user_id serial PRIMARY KEY,
......@@ -45,6 +55,8 @@ CREATE TABLE places (
);
CREATE INDEX places_parent_index ON places (parent);
-- XXX: Potřebujeme operator class text_pattern_ops, aby index fungoval na prefixové LIKE
CREATE INDEX places_noacc_index ON places ((lower(f_unaccent(name))) text_pattern_ops);
-- Rekurzivní dotaz na nadřazené regiony:
-- WITH RECURSIVE parent_regions(parent, place_id) AS (
......
SET ROLE 'mo_osmo';
-- Musí udělat správce (ale uvnitř naší DB):
-- CREATE EXTENSION unaccent;
CREATE OR REPLACE FUNCTION f_unaccent(text)
RETURNS text AS
$func$
SELECT unaccent('unaccent', $1)
$func$ LANGUAGE sql IMMUTABLE SET search_path = public, pg_temp;
CREATE INDEX places_noacc_index ON places ((lower(f_unaccent(name))) text_pattern_ops);
......@@ -16,6 +16,7 @@ from sqlalchemy.orm.attributes import get_history
from sqlalchemy.dialects.postgresql import JSONB
from sqlalchemy.ext.declarative import declarative_base
from sqlalchemy.sql.expression import CTE
from sqlalchemy.sql.functions import ReturnTypeFromArgs
from sqlalchemy.sql.sqltypes import Numeric
from typing import Optional, List, Tuple
......@@ -34,6 +35,11 @@ else:
from sqlalchemy import Enum
# Funkce f_unaccent je definovaná v db.ddl, naučme Alchymii volat ji:
class f_unaccent(ReturnTypeFromArgs):
pass
Base = declarative_base()
metadata = Base.metadata
......
from flask import request
from flask.json import jsonify
from sqlalchemy import func
from sqlalchemy.orm import joinedload
import werkzeug.exceptions
......@@ -22,12 +23,10 @@ def api_find_town():
elif '%' in query:
return jsonify(error='Nepovolené znaky ve jménu obce.')
else:
# FIXME: Hledání bez akcentů
# FIXME: Hodil by se index...
max_places = 50
places = (db.get_session().query(db.Place)
.filter_by(level=3)
.filter(db.Place.name.ilike(query + '%'))
.filter(func.lower(db.f_unaccent(db.Place.name)).like(func.lower(db.f_unaccent(query + '%'))))
.options(joinedload(db.Place.parent_place))
.order_by(db.Place.name, db.Place.place_id)
.limit(max_places)
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment