// Mila - Membership Management System // Database Schema Documentation // // This file can be used with: // - https://dbdiagram.io // - https://dbdocs.io // - VS Code Extensions: "DBML Language" or "dbdiagram.io" // // Version: 1.2 // Last Updated: 2025-11-13 Project mila_membership_management { database_type: 'PostgreSQL' Note: ''' # Mila Membership Management System A membership management application for small to mid-sized clubs. ## Key Features: - User authentication (OIDC + Password with secure account linking) - Member management with flexible custom fields - Bidirectional email synchronization between users and members - Full-text search capabilities (tsvector) - Fuzzy search with trigram matching (pg_trgm) - GDPR-compliant data management ## Domains: - **Accounts**: User authentication and session management - **Membership**: Club member data and custom fields ## Required PostgreSQL Extensions: - uuid-ossp (UUID generation) - citext (case-insensitive text) - pg_trgm (trigram-based fuzzy search) ''' } // ============================================ // ACCOUNTS DOMAIN // ============================================ Table users { id uuid [pk, not null, default: `gen_random_uuid()`, note: 'Primary identifier'] email citext [not null, unique, note: 'Email address (case-insensitive) - source of truth when linked to member'] hashed_password text [null, note: 'Bcrypt-hashed password (null for OIDC-only users)'] oidc_id text [null, unique, note: 'External OIDC identifier from authentication provider (e.g., Rauthy)'] member_id uuid [null, unique, note: 'Optional 1:1 link to member record'] indexes { email [unique, name: 'users_unique_email_index'] oidc_id [unique, name: 'users_unique_oidc_id_index'] member_id [unique, name: 'users_unique_member_index'] } Note: ''' **User Authentication Table** Handles user login accounts with two authentication strategies: 1. Password-based authentication (email + hashed_password) 2. OIDC/SSO authentication (email + oidc_id) **Relationship with Members:** - Optional 1:1 relationship with members table (0..1 ↔ 0..1) - A user can have 0 or 1 member (user.member_id can be NULL) - A member can have 0 or 1 user (optional has_one relationship) - Both entities can exist independently - When linked, user.email is the source of truth - Email changes sync bidirectionally between user ↔ member **Constraints:** - At least one auth method required (password OR oidc_id) - Email must be unique across all users - OIDC ID must be unique if present - Member can only be linked to one user (enforced by unique index) **Deletion Behavior:** - When member is deleted → user.member_id set to NULL (user preserved) - When user is deleted → member.user relationship cleared (member preserved) ''' } Table tokens { jti text [pk, not null, note: 'JWT ID - unique token identifier'] subject text [not null, note: 'Token subject (usually user ID)'] purpose text [not null, note: 'Token purpose (e.g., "access", "refresh", "password_reset")'] expires_at timestamp [not null, note: 'Token expiration timestamp (UTC)'] extra_data jsonb [null, note: 'Additional token metadata'] created_at timestamp [not null, default: `now() AT TIME ZONE 'utc'`, note: 'Creation timestamp (UTC)'] updated_at timestamp [not null, default: `now() AT TIME ZONE 'utc'`, note: 'Last update timestamp (UTC)'] indexes { subject [name: 'tokens_subject_idx', note: 'For user token lookups'] expires_at [name: 'tokens_expires_at_idx', note: 'For token cleanup queries'] purpose [name: 'tokens_purpose_idx', note: 'For purpose-based queries'] } Note: ''' **AshAuthentication Token Management** Stores JWT tokens for authentication and authorization. **Token Purposes:** - `access`: Short-lived access tokens for API requests - `refresh`: Long-lived tokens for obtaining new access tokens - `password_reset`: Temporary tokens for password reset flow - `email_confirmation`: Temporary tokens for email verification **Token Lifecycle:** - Tokens are created during login/registration - Can be revoked by deleting the record - Expired tokens should be cleaned up periodically - `store_all_tokens? true` enables token tracking ''' } // ============================================ // MEMBERSHIP DOMAIN // ============================================ Table members { id uuid [pk, not null, default: `uuid_generate_v7()`, note: 'UUIDv7 primary key (sortable by creation time)'] first_name text [not null, note: 'Member first name (min length: 1)'] last_name text [not null, note: 'Member last name (min length: 1)'] email text [not null, unique, note: 'Member email address (5-254 chars, validated)'] birth_date date [null, note: 'Date of birth (cannot be in future)'] paid boolean [null, note: 'Payment status flag'] phone_number text [null, note: 'Contact phone number (format: +?[0-9\- ]{6,20})'] join_date date [null, note: 'Date when member joined club (cannot be in future)'] exit_date date [null, note: 'Date when member left club (must be after join_date)'] notes text [null, note: 'Additional notes about member'] city text [null, note: 'City of residence'] street text [null, note: 'Street name'] house_number text [null, note: 'House number'] postal_code text [null, note: '5-digit German postal code'] search_vector tsvector [null, note: 'Full-text search index (auto-generated)'] indexes { email [unique, name: 'members_unique_email_index'] search_vector [type: gin, name: 'members_search_vector_idx', note: 'GIN index for full-text search (tsvector)'] first_name [type: gin, name: 'members_first_name_trgm_idx', note: 'GIN trigram index for fuzzy search'] last_name [type: gin, name: 'members_last_name_trgm_idx', note: 'GIN trigram index for fuzzy search'] email [type: gin, name: 'members_email_trgm_idx', note: 'GIN trigram index for fuzzy search'] city [type: gin, name: 'members_city_trgm_idx', note: 'GIN trigram index for fuzzy search'] street [type: gin, name: 'members_street_trgm_idx', note: 'GIN trigram index for fuzzy search'] notes [type: gin, name: 'members_notes_trgm_idx', note: 'GIN trigram index for fuzzy search'] email [name: 'members_email_idx', note: 'B-tree index for exact lookups'] last_name [name: 'members_last_name_idx', note: 'B-tree index for name sorting'] join_date [name: 'members_join_date_idx', note: 'B-tree index for date filters'] (paid) [name: 'members_paid_idx', type: btree, note: 'Partial index WHERE paid IS NOT NULL'] } Note: ''' **Club Member Master Data** Core entity for membership management containing: - Personal information (name, birth date, email) - Contact details (phone, address) - Membership status (join/exit dates, payment status) - Additional notes **Email Synchronization:** When a member is linked to a user: - User.email is the source of truth (overwrites member.email on link) - Subsequent changes to either email sync bidirectionally - Validates that email is not already used by another unlinked user **Search Capabilities:** 1. Full-Text Search (tsvector): - `search_vector` is auto-updated via trigger - Weighted fields: first_name (A), last_name (A), email (B), notes (B) - GIN index for fast text search 2. Fuzzy Search (pg_trgm): - Trigram-based similarity matching - 6 GIN trigram indexes on searchable fields - Configurable similarity threshold (default 0.2) - Supports typos and partial matches **Relationships:** - Optional 1:1 with users (0..1 ↔ 0..1) - authentication account - 1:N with custom_field_values (custom dynamic fields) **Validation Rules:** - first_name, last_name: min 1 character - email: 5-254 characters, valid email format - birth_date: cannot be in future - join_date: cannot be in future - exit_date: must be after join_date (if both present) - phone_number: matches pattern ^\+?[0-9\- ]{6,20}$ - postal_code: exactly 5 digits ''' } Table custom_field_values { id uuid [pk, not null, default: `gen_random_uuid()`, note: 'Primary identifier'] value jsonb [null, note: 'Union type value storage (format: {type: "string", value: "example"})'] member_id uuid [not null, note: 'Link to member'] custom_field_id uuid [not null, note: 'Link to custom field definition'] indexes { (member_id, custom_field_id) [unique, name: 'custom_field_values_unique_custom_field_per_member_index', note: 'One custom field value per custom field per member'] member_id [name: 'custom_field_values_member_id_idx'] custom_field_id [name: 'custom_field_values_custom_field_id_idx'] } Note: ''' **Dynamic Custom Member Field Values** Provides flexible, extensible attributes for members beyond the fixed schema. **Value Storage:** - Stored as JSONB map with type discrimination - Format: `{type: "string|integer|boolean|date|email", value: }` - Allows multiple data types in single column **Supported Types:** - `string`: Text data - `integer`: Numeric data - `boolean`: True/False flags - `date`: Date values - `email`: Validated email addresses **Constraints:** - Each member can have only ONE custom field value per custom field - Custom field values are deleted when member is deleted (CASCADE) - Custom field cannot be deleted if custom field values exist (RESTRICT) **Use Cases:** - Custom membership numbers - Additional contact methods - Club-specific attributes - Flexible data model without schema migrations ''' } Table custom_fields { id uuid [pk, not null, default: `gen_random_uuid()`, note: 'Primary identifier'] name text [not null, unique, note: 'CustomFieldValue name/identifier (e.g., "membership_number")'] slug text [not null, unique, note: 'URL-friendly, immutable identifier (e.g., "membership-number"). Auto-generated from name.'] value_type text [not null, note: 'Data type: string | integer | boolean | date | email'] description text [null, note: 'Human-readable description'] immutable boolean [not null, default: false, note: 'If true, value cannot be changed after creation'] required boolean [not null, default: false, note: 'If true, all members must have this custom field'] indexes { name [unique, name: 'custom_fields_unique_name_index'] slug [unique, name: 'custom_fields_unique_slug_index'] } Note: ''' **CustomFieldValue Type Definitions** Defines the schema and behavior for custom member custom_field_values. **Attributes:** - `name`: Unique identifier for the custom field - `slug`: URL-friendly, human-readable identifier (auto-generated, immutable) - `value_type`: Enforces data type consistency - `description`: Documentation for users/admins - `immutable`: Prevents changes after initial creation (e.g., membership numbers) - `required`: Enforces that all members must have this custom field **Slug Generation:** - Automatically generated from `name` on creation - Immutable after creation (does not change when name is updated) - Lowercase, spaces replaced with hyphens, special characters removed - UTF-8 support (ä → a, ß → ss, etc.) - Used for human-readable identifiers (CSV export/import, API, etc.) - Examples: "Mobile Phone" → "mobile-phone", "Café Müller" → "cafe-muller" **Constraints:** - `value_type` must be one of: string, integer, boolean, date, email - `name` must be unique across all custom fields - `slug` must be unique across all custom fields - `slug` cannot be empty (validated on creation) - Cannot be deleted if custom_field_values reference it (ON DELETE RESTRICT) **Examples:** - Membership Number (string, immutable, required) → slug: "membership-number" - Emergency Contact (string, mutable, optional) → slug: "emergency-contact" - Certified Trainer (boolean, mutable, optional) → slug: "certified-trainer" - Certification Date (date, immutable, optional) → slug: "certification-date" ''' } // ============================================ // RELATIONSHIPS // ============================================ // Optional 1:1 User ↔ Member Link // - A user can have 0 or 1 linked member (optional) // - A member can have 0 or 1 linked user (optional) // - Both can exist independently // - ON DELETE SET NULL: User preserved when member deleted // - Email Synchronization: When linking occurs, user.email becomes source of truth Ref: users.member_id - members.id [delete: set null] // Member → Properties (1:N) // - One member can have multiple custom_field_values // - Each custom field value belongs to exactly one member // - ON DELETE CASCADE: Properties deleted when member deleted // - UNIQUE constraint: One custom field value per custom field per member Ref: custom_field_values.member_id > members.id [delete: cascade] // CustomFieldValue → CustomField (N:1) // - Many custom_field_values can reference one custom field // - CustomFieldValue type defines the schema/behavior // - ON DELETE RESTRICT: Cannot delete type if custom_field_values exist Ref: custom_field_values.custom_field_id > custom_fields.id [delete: restrict] // ============================================ // ENUMS // ============================================ // Valid data types for custom field values // Determines how CustomFieldValue.value is interpreted Enum custom_field_value_type { string [note: 'Text data'] integer [note: 'Numeric data'] boolean [note: 'True/False flags'] date [note: 'Date values'] email [note: 'Validated email addresses'] } // Token purposes for different authentication flows Enum token_purpose { access [note: 'Short-lived access tokens'] refresh [note: 'Long-lived refresh tokens'] password_reset [note: 'Password reset tokens'] email_confirmation [note: 'Email verification tokens'] } // ============================================ // TABLE GROUPS // ============================================ TableGroup accounts_domain { users tokens Note: ''' **Accounts Domain** Handles user authentication and session management using AshAuthentication. Supports multiple authentication strategies (Password, OIDC). ''' } TableGroup membership_domain { members custom_field_values custom_fields Note: ''' **Membership Domain** Core business logic for club membership management. Supports flexible, extensible member data model. ''' }