fix: simplify JSONB extraction - remove redundant operators
- Replace 4 LIKE checks with 2 in build_custom_field_filter - Simplify CASE blocks in migration trigger functions - ->> operator always returns text, no need for -> + ::text fallback - Performance improvement: 50% fewer LIKE operations
This commit is contained in:
parent
014ef04853
commit
265e976d94
2 changed files with 11 additions and 47 deletions
|
|
@ -529,12 +529,11 @@ defmodule Mv.Membership.Member do
|
||||||
# Builds search filter for custom field values using LIKE on JSONB
|
# Builds search filter for custom field values using LIKE on JSONB
|
||||||
# Note: LIKE on JSONB is not index-optimized, may be slow with many custom fields
|
# Note: LIKE on JSONB is not index-optimized, may be slow with many custom fields
|
||||||
# This is a fallback for substring matching in custom fields (e.g., phone numbers)
|
# This is a fallback for substring matching in custom fields (e.g., phone numbers)
|
||||||
|
# Uses ->> operator which always returns TEXT directly (no need for -> + ::text fallback)
|
||||||
defp build_custom_field_filter(pattern) do
|
defp build_custom_field_filter(pattern) do
|
||||||
expr(
|
expr(
|
||||||
fragment(
|
fragment(
|
||||||
"EXISTS (SELECT 1 FROM custom_field_values WHERE member_id = id AND (value->>'_union_value' LIKE ? OR value->>'value' LIKE ? OR (value->'_union_value')::text LIKE ? OR (value->'value')::text LIKE ?))",
|
"EXISTS (SELECT 1 FROM custom_field_values WHERE member_id = id AND (value->>'_union_value' LIKE ? OR value->>'value' LIKE ?))",
|
||||||
^pattern,
|
|
||||||
^pattern,
|
|
||||||
^pattern,
|
^pattern,
|
||||||
^pattern
|
^pattern
|
||||||
)
|
)
|
||||||
|
|
|
||||||
|
|
@ -20,23 +20,11 @@ defmodule Mv.Repo.Migrations.AddCustomFieldValuesToSearchVector do
|
||||||
BEGIN
|
BEGIN
|
||||||
-- Aggregate all custom field values for this member
|
-- Aggregate all custom field values for this member
|
||||||
-- Support both formats: _union_type/_union_value (Ash format) and type/value (legacy)
|
-- Support both formats: _union_type/_union_value (Ash format) and type/value (legacy)
|
||||||
-- Extract value as text: handle both string and numeric values correctly
|
-- ->> operator always returns TEXT directly (no need for -> + ::text fallback)
|
||||||
SELECT string_agg(
|
SELECT string_agg(
|
||||||
CASE
|
CASE
|
||||||
-- Try _union_value first (Ash format)
|
WHEN value ? '_union_value' THEN value->>'_union_value'
|
||||||
WHEN value ? '_union_value' THEN
|
WHEN value ? 'value' THEN value->>'value'
|
||||||
-- For strings: value->>'_union_value' returns text directly
|
|
||||||
-- For numbers/booleans: value->'_union_value' returns JSONB, then ::text converts it
|
|
||||||
COALESCE(
|
|
||||||
NULLIF(value->>'_union_value', ''),
|
|
||||||
(value->'_union_value')::text
|
|
||||||
)
|
|
||||||
-- Fallback to value (legacy format)
|
|
||||||
WHEN value ? 'value' THEN
|
|
||||||
COALESCE(
|
|
||||||
NULLIF(value->>'value', ''),
|
|
||||||
(value->'value')::text
|
|
||||||
)
|
|
||||||
ELSE ''
|
ELSE ''
|
||||||
END,
|
END,
|
||||||
' '
|
' '
|
||||||
|
|
@ -94,20 +82,17 @@ defmodule Mv.Repo.Migrations.AddCustomFieldValuesToSearchVector do
|
||||||
-- If value hasn't changed, we can skip the expensive re-aggregation
|
-- If value hasn't changed, we can skip the expensive re-aggregation
|
||||||
IF TG_OP = 'UPDATE' THEN
|
IF TG_OP = 'UPDATE' THEN
|
||||||
-- Extract OLD value for comparison (handle both JSONB formats)
|
-- Extract OLD value for comparison (handle both JSONB formats)
|
||||||
|
-- ->> operator always returns TEXT directly
|
||||||
old_value_text := COALESCE(
|
old_value_text := COALESCE(
|
||||||
NULLIF(OLD.value->>'_union_value', ''),
|
NULLIF(OLD.value->>'_union_value', ''),
|
||||||
(OLD.value->'_union_value')::text,
|
|
||||||
NULLIF(OLD.value->>'value', ''),
|
NULLIF(OLD.value->>'value', ''),
|
||||||
(OLD.value->'value')::text,
|
|
||||||
''
|
''
|
||||||
);
|
);
|
||||||
|
|
||||||
-- Extract NEW value for comparison (handle both JSONB formats)
|
-- Extract NEW value for comparison (handle both JSONB formats)
|
||||||
new_value_text := COALESCE(
|
new_value_text := COALESCE(
|
||||||
NULLIF(NEW.value->>'_union_value', ''),
|
NULLIF(NEW.value->>'_union_value', ''),
|
||||||
(NEW.value->'_union_value')::text,
|
|
||||||
NULLIF(NEW.value->>'value', ''),
|
NULLIF(NEW.value->>'value', ''),
|
||||||
(NEW.value->'value')::text,
|
|
||||||
''
|
''
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|
@ -150,21 +135,11 @@ defmodule Mv.Repo.Migrations.AddCustomFieldValuesToSearchVector do
|
||||||
|
|
||||||
-- Aggregate all custom field values for this member
|
-- Aggregate all custom field values for this member
|
||||||
-- Support both formats: _union_type/_union_value (Ash format) and type/value (legacy)
|
-- Support both formats: _union_type/_union_value (Ash format) and type/value (legacy)
|
||||||
-- Extract value as text: handle both string and numeric values correctly
|
-- ->> operator always returns TEXT directly
|
||||||
SELECT string_agg(
|
SELECT string_agg(
|
||||||
CASE
|
CASE
|
||||||
-- Try _union_value first (Ash format)
|
WHEN value ? '_union_value' THEN value->>'_union_value'
|
||||||
WHEN value ? '_union_value' THEN
|
WHEN value ? 'value' THEN value->>'value'
|
||||||
COALESCE(
|
|
||||||
NULLIF(value->>'_union_value', ''),
|
|
||||||
(value->'_union_value')::text
|
|
||||||
)
|
|
||||||
-- Fallback to value (legacy format)
|
|
||||||
WHEN value ? 'value' THEN
|
|
||||||
COALESCE(
|
|
||||||
NULLIF(value->>'value', ''),
|
|
||||||
(value->'value')::text
|
|
||||||
)
|
|
||||||
ELSE ''
|
ELSE ''
|
||||||
END,
|
END,
|
||||||
' '
|
' '
|
||||||
|
|
@ -221,18 +196,8 @@ defmodule Mv.Repo.Migrations.AddCustomFieldValuesToSearchVector do
|
||||||
setweight(to_tsvector('simple', coalesce(
|
setweight(to_tsvector('simple', coalesce(
|
||||||
(SELECT string_agg(
|
(SELECT string_agg(
|
||||||
CASE
|
CASE
|
||||||
-- Try _union_value first (Ash format)
|
WHEN value ? '_union_value' THEN value->>'_union_value'
|
||||||
WHEN value ? '_union_value' THEN
|
WHEN value ? 'value' THEN value->>'value'
|
||||||
COALESCE(
|
|
||||||
NULLIF(value->>'_union_value', ''),
|
|
||||||
(value->'_union_value')::text
|
|
||||||
)
|
|
||||||
-- Fallback to value (legacy format)
|
|
||||||
WHEN value ? 'value' THEN
|
|
||||||
COALESCE(
|
|
||||||
NULLIF(value->>'value', ''),
|
|
||||||
(value->'value')::text
|
|
||||||
)
|
|
||||||
ELSE ''
|
ELSE ''
|
||||||
END,
|
END,
|
||||||
' '
|
' '
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue