This commit is contained in:
parent
10e5270273
commit
47f18e9ef3
4 changed files with 264 additions and 35 deletions
|
|
@ -132,11 +132,17 @@ Member (1) → (N) Properties
|
|||
### Performance Indexes
|
||||
|
||||
**members:**
|
||||
- `search_vector` (GIN) - Full-text search
|
||||
- `email` - Email lookups
|
||||
- `last_name` - Name sorting
|
||||
- `join_date` - Date filtering
|
||||
- `paid` (partial) - Payment status queries
|
||||
- `search_vector` (GIN) - Full-text search (tsvector)
|
||||
- `first_name` (GIN trgm) - Fuzzy search on first name
|
||||
- `last_name` (GIN trgm) - Fuzzy search on last name
|
||||
- `email` (GIN trgm) - Fuzzy search on email
|
||||
- `city` (GIN trgm) - Fuzzy search on city
|
||||
- `street` (GIN trgm) - Fuzzy search on street
|
||||
- `notes` (GIN trgm) - Fuzzy search on notes
|
||||
- `email` (B-tree) - Exact email lookups
|
||||
- `last_name` (B-tree) - Name sorting
|
||||
- `join_date` (B-tree) - Date filtering
|
||||
- `paid` (partial B-tree) - Payment status queries
|
||||
|
||||
**properties:**
|
||||
- `member_id` - Member property lookups
|
||||
|
|
@ -172,6 +178,64 @@ SELECT * FROM members
|
|||
WHERE search_vector @@ to_tsquery('simple', 'john & doe');
|
||||
```
|
||||
|
||||
## Fuzzy Search (Trigram-based)
|
||||
|
||||
### Implementation
|
||||
- **Extension:** `pg_trgm` (PostgreSQL Trigram)
|
||||
- **Index Type:** GIN with `gin_trgm_ops` operator class
|
||||
- **Similarity Threshold:** 0.2 (default, configurable)
|
||||
- **Added:** November 2025 (PR #187, closes #162)
|
||||
|
||||
### How It Works
|
||||
Fuzzy search combines multiple search strategies:
|
||||
1. **Full-text search** - Primary filter using tsvector
|
||||
2. **Trigram similarity** - `similarity(field, query) > threshold`
|
||||
3. **Word similarity** - `word_similarity(query, field) > threshold`
|
||||
4. **Substring matching** - `LIKE` and `ILIKE` for exact substrings
|
||||
5. **Modulo operator** - `query % field` for quick similarity check
|
||||
|
||||
### Indexed Fields for Fuzzy Search
|
||||
- `first_name` - GIN trigram index
|
||||
- `last_name` - GIN trigram index
|
||||
- `email` - GIN trigram index
|
||||
- `city` - GIN trigram index
|
||||
- `street` - GIN trigram index
|
||||
- `notes` - GIN trigram index
|
||||
|
||||
### Usage Example (Ash Action)
|
||||
```elixir
|
||||
# In LiveView or context
|
||||
Member.fuzzy_search(Member, query: "john", similarity_threshold: 0.2)
|
||||
|
||||
# Or using Ash Query directly
|
||||
Member
|
||||
|> Ash.Query.for_read(:search, %{query: "john", similarity_threshold: 0.2})
|
||||
|> Mv.Membership.read!()
|
||||
```
|
||||
|
||||
### Usage Example (SQL)
|
||||
```sql
|
||||
-- Trigram similarity search
|
||||
SELECT * FROM members
|
||||
WHERE similarity(first_name, 'john') > 0.2
|
||||
OR similarity(last_name, 'doe') > 0.2
|
||||
ORDER BY similarity(first_name, 'john') DESC;
|
||||
|
||||
-- Word similarity (better for partial matches)
|
||||
SELECT * FROM members
|
||||
WHERE word_similarity('john', first_name) > 0.2;
|
||||
|
||||
-- Quick similarity check with % operator
|
||||
SELECT * FROM members
|
||||
WHERE 'john' % first_name;
|
||||
```
|
||||
|
||||
### Performance Considerations
|
||||
- **GIN indexes** speed up trigram operations significantly
|
||||
- **Similarity threshold** of 0.2 balances precision and recall
|
||||
- **Combined approach** (FTS + trigram) provides best results
|
||||
- Lower threshold = more results but less specific
|
||||
|
||||
## Database Extensions
|
||||
|
||||
### Required PostgreSQL Extensions
|
||||
|
|
@ -184,10 +248,17 @@ WHERE search_vector @@ to_tsquery('simple', 'john & doe');
|
|||
- Purpose: Case-insensitive text type
|
||||
- Used for: `users.email` (case-insensitive email matching)
|
||||
|
||||
3. **pg_trgm**
|
||||
- Purpose: Trigram-based fuzzy text search and similarity matching
|
||||
- Used for: Fuzzy member search with similarity scoring
|
||||
- Operators: `%` (similarity), `word_similarity()`, `similarity()`
|
||||
- Added in: Migration `20251001141005_add_trigram_to_members.exs`
|
||||
|
||||
### Installation
|
||||
```sql
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
CREATE EXTENSION IF NOT EXISTS "citext";
|
||||
CREATE EXTENSION IF NOT EXISTS "pg_trgm";
|
||||
```
|
||||
|
||||
## Migration Strategy
|
||||
|
|
@ -215,6 +286,7 @@ priv/repo/migrations/
|
|||
├── 20250620110850_add_accounts_domain.exs
|
||||
├── 20250912085235_AddSearchVectorToMembers.exs
|
||||
├── 20250926180341_add_unique_email_to_members.exs
|
||||
├── 20251001141005_add_trigram_to_members.exs
|
||||
└── 20251016130855_add_constraints_for_user_member_and_property.exs
|
||||
```
|
||||
|
||||
|
|
@ -386,7 +458,7 @@ mix run priv/repo/seeds.exs
|
|||
|
||||
---
|
||||
|
||||
**Last Updated:** 2025-11-10
|
||||
**Schema Version:** 1.0
|
||||
**Last Updated:** 2025-11-13
|
||||
**Schema Version:** 1.1
|
||||
**Database:** PostgreSQL 17.6 (dev) / 16 (prod)
|
||||
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue