trigram indexes
This commit is contained in:
parent
b62b303995
commit
42ccf52718
3 changed files with 67 additions and 40 deletions
18
createdb.sql
18
createdb.sql
|
@ -1,3 +1,5 @@
|
|||
CREATE EXTENSION pg_trgm;
|
||||
|
||||
CREATE TABLE books (
|
||||
id varchar(16) primary key,
|
||||
title text,
|
||||
|
@ -16,6 +18,20 @@ CREATE TABLE books (
|
|||
tsv tsvector
|
||||
);
|
||||
|
||||
-- Books column indexes
|
||||
CREATE INDEX CONCURRENTLY books_lang_idx ON books (lang);
|
||||
CREATE INDEX CONCURRENTLY books_isbn_idx ON books (isbn);
|
||||
|
||||
-- Books trigram indexes
|
||||
CREATE INDEX CONCURRENTLY books_title_idx ON books USING GIN (title gin_trgm_ops);
|
||||
CREATE INDEX CONCURRENTLY books_contributor_idx ON books USING GIN (contributor gin_trgm_ops);
|
||||
CREATE INDEX CONCURRENTLY books_publisher_idx ON books USING GIN (publisher gin_trgm_ops);
|
||||
CREATE FUNCTION text(text[]) RETURNS text immutable AS $$
|
||||
select $1::text
|
||||
$$ language sql;
|
||||
CREATE INDEX CONCURRENTLY books_authors_idx ON books USING GIN (text(authors) gin_trgm_ops);
|
||||
CREATE INDEX CONCURRENTLY books_tags_idx ON books USING GIN (text(tags) gin_trgm_ops);
|
||||
|
||||
-- Books text search index
|
||||
CREATE FUNCTION books_trigger() RETURNS trigger AS $$
|
||||
declare
|
||||
|
@ -66,7 +82,7 @@ end
|
|||
$$ LANGUAGE plpgsql;
|
||||
CREATE TRIGGER tsvectorupdate BEFORE INSERT OR UPDATE
|
||||
ON books FOR EACH ROW EXECUTE PROCEDURE books_trigger();
|
||||
CREATE INDEX books_idx ON books USING GIN (tsv);
|
||||
CREATE INDEX CONCURRENTLY books_idx ON books USING GIN (tsv);
|
||||
|
||||
|
||||
CREATE TABLE news (
|
||||
|
|
|
@ -48,34 +48,45 @@ func (db *pgDB) GetNewBooks(query string, length int, start int) (books []Book,
|
|||
}
|
||||
|
||||
func (db *pgDB) getBooks(active bool, query string, length int, start int) (books []Book, num int, err error) {
|
||||
sqlQuery := db.sql.Model(&books)
|
||||
|
||||
column := []string{}
|
||||
columnParams := []interface{}{}
|
||||
searchCondition := "active = "
|
||||
if active {
|
||||
searchCondition = "true"
|
||||
} else {
|
||||
searchCondition = "false"
|
||||
}
|
||||
searchParams := []interface{}{}
|
||||
|
||||
params := []interface{}{}
|
||||
textQuery, columnQuerys := buildQuery(query)
|
||||
textQuery, columnQuerys, trigramQuerys := buildQuery(query)
|
||||
for _, c := range columnQuerys {
|
||||
searchCondition = searchCondition + " AND " + c.column + " ILIKE ?"
|
||||
params = append(params, c.value)
|
||||
searchCondition = searchCondition + " AND " + c.column + " = ?"
|
||||
searchParams = append(searchParams, c.value)
|
||||
}
|
||||
for _, c := range trigramQuerys {
|
||||
column = append(column, "word_similarity(?, "+c.column+")")
|
||||
columnParams = append(columnParams, c.value)
|
||||
searchCondition = searchCondition + " AND " + c.column + " %> ?"
|
||||
searchParams = append(searchParams, c.value)
|
||||
}
|
||||
if textQuery != "" {
|
||||
column = append(column, "ts_rank(tsv, to_tsquery(?))")
|
||||
columnParams = append(columnParams, textQuery)
|
||||
searchCondition = searchCondition + " AND to_tsquery(?) @@ tsv"
|
||||
params = append(params, textQuery)
|
||||
}
|
||||
sqlQuery = sqlQuery.Where(searchCondition, params...)
|
||||
|
||||
if textQuery != "" {
|
||||
sqlQuery = sqlQuery.Order("ts_rank(tsv, to_tsquery(?)) DESC, upload_date DESC", textQuery)
|
||||
} else {
|
||||
sqlQuery = sqlQuery.Order("upload_date DESC")
|
||||
searchParams = append(searchParams, textQuery)
|
||||
}
|
||||
|
||||
num, err = sqlQuery.
|
||||
columnStr := "*"
|
||||
order := "upload_date DESC"
|
||||
if len(column) > 0 {
|
||||
columnStr = "*, " + strings.Join(column, "+") + " AS rank"
|
||||
order = "rank DESC, upload_date DESC"
|
||||
}
|
||||
|
||||
num, err = db.sql.Model(&books).
|
||||
ColumnExpr(columnStr, columnParams...).
|
||||
Where(searchCondition, searchParams...).
|
||||
Order(order).
|
||||
Offset(start).
|
||||
Limit(length).
|
||||
SelectAndCountEstimate(100)
|
||||
|
@ -157,9 +168,8 @@ type columnq struct {
|
|||
value string
|
||||
}
|
||||
|
||||
func buildQuery(query string) (string, []columnq) {
|
||||
textQuery := ""
|
||||
columnQuerys := []columnq{}
|
||||
func buildQuery(query string) (textQuery string, columnQuerys []columnq, trigramQuerys []columnq) {
|
||||
// FIXME: does *Querys need initialization??
|
||||
words := strings.Split(query, " ")
|
||||
for _, w := range words {
|
||||
if w == "" {
|
||||
|
@ -169,28 +179,29 @@ func buildQuery(query string) (string, []columnq) {
|
|||
if len(tag) > 1 && tag[1] != "" {
|
||||
value := strings.Replace(tag[1], "%", "\\%", 0)
|
||||
value = strings.Replace(value, "_", "\\_", 0)
|
||||
expr := "%" + value + "%"
|
||||
switch tag[0] {
|
||||
case "lang":
|
||||
columnQuerys = append(columnQuerys, columnq{"lang", value})
|
||||
case "author":
|
||||
columnQuerys = append(columnQuerys, columnq{"array_to_string(authors, ' ')", expr})
|
||||
case "title":
|
||||
columnQuerys = append(columnQuerys, columnq{"title", expr})
|
||||
case "contributor":
|
||||
columnQuerys = append(columnQuerys, columnq{"contributor", expr})
|
||||
case "publisher":
|
||||
columnQuerys = append(columnQuerys, columnq{"publisher", expr})
|
||||
case "subject":
|
||||
expr = strings.ToLower(expr)
|
||||
columnQuerys = append(columnQuerys, columnq{"array_to_string(tags, ' ')", expr})
|
||||
case "tag":
|
||||
expr = strings.ToLower(expr)
|
||||
columnQuerys = append(columnQuerys, columnq{"array_to_string(tags, ' ')", expr})
|
||||
case "isbn":
|
||||
columnQuerys = append(columnQuerys, columnq{"isbn", expr})
|
||||
case "description":
|
||||
columnQuerys = append(columnQuerys, columnq{"description", expr})
|
||||
columnQuerys = append(columnQuerys, columnq{"isbn", value})
|
||||
case "author":
|
||||
// TODO how do we do trigram on arrays??
|
||||
trigramQuerys = append(trigramQuerys, columnq{"array_to_string(authors, ' ')", value})
|
||||
case "title":
|
||||
trigramQuerys = append(trigramQuerys, columnq{"title", value})
|
||||
case "contributor":
|
||||
trigramQuerys = append(trigramQuerys, columnq{"contributor", value})
|
||||
case "publisher":
|
||||
trigramQuerys = append(trigramQuerys, columnq{"publisher", value})
|
||||
case "subject":
|
||||
trigramQuerys = append(trigramQuerys, columnq{"array_to_string(tags, ' ')", value})
|
||||
case "tag":
|
||||
trigramQuerys = append(trigramQuerys, columnq{"array_to_string(tags, ' ')", value})
|
||||
default:
|
||||
if len(textQuery) != 0 {
|
||||
textQuery += " | "
|
||||
}
|
||||
textQuery += w
|
||||
}
|
||||
} else {
|
||||
if len(textQuery) != 0 {
|
||||
|
@ -204,5 +215,5 @@ func buildQuery(query string) (string, []columnq) {
|
|||
textQuery += w
|
||||
}
|
||||
}
|
||||
return textQuery, columnQuerys
|
||||
return
|
||||
}
|
||||
|
|
|
@ -36,10 +36,10 @@ func (db *pgDB) AddUser(name string, pass string) error {
|
|||
log.Error("Error hashing password: ", err)
|
||||
return errors.New("An error happen storing the password")
|
||||
}
|
||||
return db.AddRawUser(name, hpass, salt, "")
|
||||
return db.addRawUser(name, hpass, salt, "")
|
||||
}
|
||||
|
||||
func (db *DB) AddRawUser(name string, hpass []byte, salt []byte, role string) error {
|
||||
func (db *pgDB) addRawUser(name string, hpass []byte, salt []byte, role string) error {
|
||||
u := user{
|
||||
Username: name,
|
||||
Password: hpass,
|
||||
|
|
Reference in a new issue