diff --git a/priv/repo/migrations/20251204123714_add_custom_field_values_to_search_vector.exs b/priv/repo/migrations/20251204123714_add_custom_field_values_to_search_vector.exs new file mode 100644 index 0000000..1c8fbc9 --- /dev/null +++ b/priv/repo/migrations/20251204123714_add_custom_field_values_to_search_vector.exs @@ -0,0 +1,294 @@ +defmodule Mv.Repo.Migrations.AddCustomFieldValuesToSearchVector do + @moduledoc """ + Extends the search_vector in members table to include custom_field_values. + + This migration: + 1. Updates the members_search_vector_trigger() function to include custom field values + 2. Creates a trigger function to update member search_vector when custom_field_values change + 3. Creates a trigger on custom_field_values table + 4. Updates existing search_vector values for all members + """ + + use Ecto.Migration + + def up do + # Update the main trigger function to include custom_field_values + execute(""" + CREATE OR REPLACE FUNCTION members_search_vector_trigger() RETURNS trigger AS $$ + DECLARE + custom_values_text text; + BEGIN + -- Aggregate all custom field values for this member + -- Support both formats: _union_type/_union_value (Ash format) and type/value (legacy) + -- Extract value as text: handle both string and numeric values correctly + SELECT string_agg( + CASE + -- Try _union_value first (Ash format) + WHEN value ? '_union_value' THEN + -- 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 '' + END, + ' ' + ) + INTO custom_values_text + FROM custom_field_values + WHERE member_id = NEW.id AND value IS NOT NULL; + + -- Build search_vector with member fields and custom field values + NEW.search_vector := + setweight(to_tsvector('simple', coalesce(NEW.first_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(NEW.last_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(NEW.email, '')), 'B') || + setweight(to_tsvector('simple', coalesce(NEW.phone_number, '')), 'C') || + setweight(to_tsvector('simple', coalesce(NEW.join_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(NEW.exit_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(NEW.notes, '')), 'B') || + setweight(to_tsvector('simple', coalesce(NEW.city, '')), 'C') || + setweight(to_tsvector('simple', coalesce(NEW.street, '')), 'C') || + setweight(to_tsvector('simple', coalesce(NEW.house_number::text, '')), 'C') || + setweight(to_tsvector('simple', coalesce(NEW.postal_code::text, '')), 'C') || + setweight(to_tsvector('simple', coalesce(custom_values_text, '')), 'C'); + RETURN NEW; + END + $$ LANGUAGE plpgsql; + """) + + # Create trigger function to update member search_vector when custom_field_values change + # Optimized: + # 1. Only fetch required fields instead of full member record to reduce overhead + # 2. Skip re-aggregation on UPDATE if value hasn't actually changed + execute(""" + CREATE FUNCTION update_member_search_vector_from_custom_field_value() RETURNS trigger AS $$ + DECLARE + member_id_val uuid; + member_first_name text; + member_last_name text; + member_email text; + member_phone_number text; + member_join_date date; + member_exit_date date; + member_notes text; + member_city text; + member_street text; + member_house_number text; + member_postal_code text; + custom_values_text text; + old_value_text text; + new_value_text text; + BEGIN + -- Get member ID from trigger context + member_id_val := COALESCE(NEW.member_id, OLD.member_id); + + -- Optimization: For UPDATE operations, check if value actually changed + -- If value hasn't changed, we can skip the expensive re-aggregation + IF TG_OP = 'UPDATE' THEN + -- Extract OLD value for comparison (handle both JSONB formats) + old_value_text := COALESCE( + NULLIF(OLD.value->>'_union_value', ''), + (OLD.value->'_union_value')::text, + NULLIF(OLD.value->>'value', ''), + (OLD.value->'value')::text, + '' + ); + + -- Extract NEW value for comparison (handle both JSONB formats) + new_value_text := COALESCE( + NULLIF(NEW.value->>'_union_value', ''), + (NEW.value->'_union_value')::text, + NULLIF(NEW.value->>'value', ''), + (NEW.value->'value')::text, + '' + ); + + -- Check if value, member_id, or custom_field_id actually changed + -- If nothing changed, skip expensive re-aggregation + IF (old_value_text IS NOT DISTINCT FROM new_value_text) AND + (OLD.member_id IS NOT DISTINCT FROM NEW.member_id) AND + (OLD.custom_field_id IS NOT DISTINCT FROM NEW.custom_field_id) THEN + RETURN COALESCE(NEW, OLD); + END IF; + END IF; + + -- Fetch only required fields instead of full record (performance optimization) + SELECT + first_name, + last_name, + email, + phone_number, + join_date, + exit_date, + notes, + city, + street, + house_number, + postal_code + INTO + member_first_name, + member_last_name, + member_email, + member_phone_number, + member_join_date, + member_exit_date, + member_notes, + member_city, + member_street, + member_house_number, + member_postal_code + FROM members + WHERE id = member_id_val; + + -- Aggregate all custom field values for this member + -- Support both formats: _union_type/_union_value (Ash format) and type/value (legacy) + -- Extract value as text: handle both string and numeric values correctly + SELECT string_agg( + CASE + -- Try _union_value first (Ash format) + WHEN value ? '_union_value' THEN + 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 '' + END, + ' ' + ) + INTO custom_values_text + FROM custom_field_values + WHERE member_id = member_id_val AND value IS NOT NULL; + + -- Update the search_vector for the affected member + UPDATE members + SET search_vector = + setweight(to_tsvector('simple', coalesce(member_first_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(member_last_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(member_email, '')), 'B') || + setweight(to_tsvector('simple', coalesce(member_phone_number, '')), 'C') || + setweight(to_tsvector('simple', coalesce(member_join_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(member_exit_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(member_notes, '')), 'B') || + setweight(to_tsvector('simple', coalesce(member_city, '')), 'C') || + setweight(to_tsvector('simple', coalesce(member_street, '')), 'C') || + setweight(to_tsvector('simple', coalesce(member_house_number::text, '')), 'C') || + setweight(to_tsvector('simple', coalesce(member_postal_code::text, '')), 'C') || + setweight(to_tsvector('simple', coalesce(custom_values_text, '')), 'C') + WHERE id = member_id_val; + + RETURN COALESCE(NEW, OLD); + END + $$ LANGUAGE plpgsql; + """) + + # Create trigger on custom_field_values table + execute(""" + CREATE TRIGGER update_member_search_vector_on_custom_field_value_change + AFTER INSERT OR UPDATE OR DELETE ON custom_field_values + FOR EACH ROW + EXECUTE FUNCTION update_member_search_vector_from_custom_field_value() + """) + + # Update existing search_vector values for all members + execute(""" + UPDATE members m + SET search_vector = + setweight(to_tsvector('simple', coalesce(m.first_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(m.last_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(m.email, '')), 'B') || + setweight(to_tsvector('simple', coalesce(m.phone_number, '')), 'C') || + setweight(to_tsvector('simple', coalesce(m.join_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(m.exit_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(m.notes, '')), 'B') || + setweight(to_tsvector('simple', coalesce(m.city, '')), 'C') || + setweight(to_tsvector('simple', coalesce(m.street, '')), 'C') || + setweight(to_tsvector('simple', coalesce(m.house_number::text, '')), 'C') || + setweight(to_tsvector('simple', coalesce(m.postal_code::text, '')), 'C') || + setweight(to_tsvector('simple', coalesce( + (SELECT string_agg( + CASE + -- Try _union_value first (Ash format) + WHEN value ? '_union_value' THEN + 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 '' + END, + ' ' + ) + FROM custom_field_values + WHERE member_id = m.id AND value IS NOT NULL), + '' + )), 'C') + """) + end + + def down do + # Drop trigger on custom_field_values + execute( + "DROP TRIGGER IF EXISTS update_member_search_vector_on_custom_field_value_change ON custom_field_values" + ) + + # Drop trigger function + execute("DROP FUNCTION IF EXISTS update_member_search_vector_from_custom_field_value()") + + # Restore original trigger function without custom_field_values + execute(""" + CREATE OR REPLACE FUNCTION members_search_vector_trigger() RETURNS trigger AS $$ + BEGIN + NEW.search_vector := + setweight(to_tsvector('simple', coalesce(NEW.first_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(NEW.last_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(NEW.email, '')), 'B') || + setweight(to_tsvector('simple', coalesce(NEW.phone_number, '')), 'C') || + setweight(to_tsvector('simple', coalesce(NEW.join_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(NEW.exit_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(NEW.notes, '')), 'B') || + setweight(to_tsvector('simple', coalesce(NEW.city, '')), 'C') || + setweight(to_tsvector('simple', coalesce(NEW.street, '')), 'C') || + setweight(to_tsvector('simple', coalesce(NEW.house_number::text, '')), 'C') || + setweight(to_tsvector('simple', coalesce(NEW.postal_code::text, '')), 'C'); + RETURN NEW; + END + $$ LANGUAGE plpgsql; + """) + + # Update existing search_vector values to remove custom_field_values + execute(""" + UPDATE members m + SET search_vector = + setweight(to_tsvector('simple', coalesce(m.first_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(m.last_name, '')), 'A') || + setweight(to_tsvector('simple', coalesce(m.email, '')), 'B') || + setweight(to_tsvector('simple', coalesce(m.phone_number, '')), 'C') || + setweight(to_tsvector('simple', coalesce(m.join_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(m.exit_date::text, '')), 'D') || + setweight(to_tsvector('simple', coalesce(m.notes, '')), 'B') || + setweight(to_tsvector('simple', coalesce(m.city, '')), 'C') || + setweight(to_tsvector('simple', coalesce(m.street, '')), 'C') || + setweight(to_tsvector('simple', coalesce(m.house_number::text, '')), 'C') || + setweight(to_tsvector('simple', coalesce(m.postal_code::text, '')), 'C') + """) + end +end diff --git a/priv/resource_snapshots/repo/members/20251204123714.json b/priv/resource_snapshots/repo/members/20251204123714.json new file mode 100644 index 0000000..8f3bf6c --- /dev/null +++ b/priv/resource_snapshots/repo/members/20251204123714.json @@ -0,0 +1,202 @@ +{ + "attributes": [ + { + "allow_nil?": false, + "default": "fragment(\"uuid_generate_v7()\")", + "generated?": false, + "precision": null, + "primary_key?": true, + "references": null, + "scale": null, + "size": null, + "source": "id", + "type": "uuid" + }, + { + "allow_nil?": false, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "first_name", + "type": "text" + }, + { + "allow_nil?": false, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "last_name", + "type": "text" + }, + { + "allow_nil?": false, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "email", + "type": "text" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "paid", + "type": "boolean" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "phone_number", + "type": "text" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "join_date", + "type": "date" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "exit_date", + "type": "date" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "notes", + "type": "text" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "city", + "type": "text" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "street", + "type": "text" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "house_number", + "type": "text" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "postal_code", + "type": "text" + }, + { + "allow_nil?": true, + "default": "nil", + "generated?": false, + "precision": null, + "primary_key?": false, + "references": null, + "scale": null, + "size": null, + "source": "search_vector", + "type": "tsvector" + } + ], + "base_filter": null, + "check_constraints": [], + "custom_indexes": [], + "custom_statements": [], + "has_create_action": true, + "hash": "247CACFA5C8FD24BDD553252E9BBF489E8FE54F60704383B6BE66C616D203A65", + "identities": [ + { + "all_tenants?": false, + "base_filter": null, + "index_name": "members_unique_email_index", + "keys": [ + { + "type": "atom", + "value": "email" + } + ], + "name": "unique_email", + "nils_distinct?": true, + "where": null + } + ], + "multitenancy": { + "attribute": null, + "global": null, + "strategy": null + }, + "repo": "Elixir.Mv.Repo", + "schema": null, + "table": "members" +} \ No newline at end of file