Files
4WDCSA.co.za/docs/migrations/004_create_membership_linking_tables.sql
twotalesanimation bd20fc0f9b feat: implement membership linking system for couples and family members
- Created membership_links table to associate secondary users with primary memberships
- Created membership_permissions table for granular permission control
- Added linkSecondaryUserToMembership() function to create links with validation
- Added getUserMembershipLink() to check access via secondary links
- Added getLinkedSecondaryUsers() to list all secondary users for a primary member
- Added unlinkSecondaryUser() to remove links
- Updated getUserMemberStatus() to check both direct and linked memberships
- Created link_membership_user processor to handle linking via API
- Created unlink_membership_user processor to handle unlinking via API
- Added .htaccess routes for linking endpoints
- Grants default permissions: access_member_areas, member_pricing, book_campsites, book_courses, book_trips
- Includes transaction safety with rollback on errors
- Includes comprehensive documentation with usage examples
- Validates primary user has active membership before allowing links
- Prevents duplicate links and self-linking
2025-12-05 10:44:52 +02:00

64 lines
2.7 KiB
SQL

-- Migration 004: Create membership linking tables
-- Purpose: Allow multiple users to share a single membership (for couples, families, etc)
-- Create membership_links table to associate secondary users with primary membership accounts
CREATE TABLE IF NOT EXISTS `membership_links` (
`link_id` INT AUTO_INCREMENT PRIMARY KEY,
`primary_user_id` INT NOT NULL,
`secondary_user_id` INT NOT NULL,
`relationship` VARCHAR(50) NOT NULL DEFAULT 'spouse', -- spouse, family member, etc
`linked_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
`created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
-- Foreign keys
CONSTRAINT `fk_membership_links_primary` FOREIGN KEY (`primary_user_id`)
REFERENCES `users`(`user_id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_membership_links_secondary` FOREIGN KEY (`secondary_user_id`)
REFERENCES `users`(`user_id`) ON DELETE CASCADE ON UPDATE CASCADE,
-- Indexes for performance
INDEX `idx_primary_user` (`primary_user_id`),
INDEX `idx_secondary_user` (`secondary_user_id`),
-- Prevent duplicate links (user cannot be linked twice)
UNIQUE KEY `unique_link` (`primary_user_id`, `secondary_user_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Create membership_permissions table to define what secondary users can access
CREATE TABLE IF NOT EXISTS `membership_permissions` (
`permission_id` INT AUTO_INCREMENT PRIMARY KEY,
`link_id` INT NOT NULL,
`permission_name` VARCHAR(100) NOT NULL, -- 'access_member_areas', 'member_pricing', 'book_campsites', etc
`granted_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
-- Foreign key
CONSTRAINT `fk_membership_permissions_link` FOREIGN KEY (`link_id`)
REFERENCES `membership_links`(`link_id`) ON DELETE CASCADE ON UPDATE CASCADE,
-- Indexes
INDEX `idx_link` (`link_id`),
-- Prevent duplicate permissions
UNIQUE KEY `unique_permission` (`link_id`, `permission_name`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Add foreign key to membership_fees to support links (optional - for tracking which membership fee covers the linked users)
-- ALTER TABLE `membership_fees` ADD COLUMN `primary_user_id` INT AFTER `user_id`;
-- This allows you to see if a fee was paid by primary or secondary user while maintaining the relationship
-- Create a view to easily get all users linked to a membership
CREATE OR REPLACE VIEW `linked_membership_users` AS
SELECT
primary_user_id,
secondary_user_id,
relationship,
linked_at
FROM membership_links
UNION ALL
SELECT
primary_user_id,
primary_user_id as secondary_user_id,
'primary' as relationship,
linked_at
FROM membership_links;