-- Restore usage migration logic to prevent duplicate user_usage records
-- This fixes the issue where users get a new empty usage record when they subscribe,
-- losing their accumulated free tier usage and preventing access to subscription privileges
-- First, recreate the migration function
CREATE OR REPLACE FUNCTION migrate_usage_to_subscription_period(user_uuid UUID)
RETURNS VOID
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public, pg_catalog, pg_temp
AS $$
DECLARE
subscription_record RECORD;
current_time TIMESTAMPTZ := NOW();
free_tier_period_start TIMESTAMPTZ;
free_tier_period_end TIMESTAMPTZ;
existing_usage_record user_usage;
subscription_period_start TIMESTAMPTZ;
subscription_period_end TIMESTAMPTZ;
BEGIN
-- Get the user's active subscription
SELECT
id,
user_id,
status,
current_period_start::TIMESTAMPTZ as period_start,
current_period_end::TIMESTAMPTZ as period_end,
created_at
INTO subscription_record
FROM subscriptions s
WHERE s.user_id = user_uuid
AND s.status IN ('active', 'trialing', 'past_due')
ORDER BY s.created_at DESC
LIMIT 1;
-- Only proceed if user has an active subscription
IF subscription_record IS NULL OR
subscription_record.period_start IS NULL OR
subscription_record.period_end IS NULL THEN
RETURN;
END IF;
-- Check if subscription is still active
IF subscription_record.period_end <= current_time THEN
RETURN;
END IF;
-- Calculate what the free tier period would be
free_tier_period_start := DATE_TRUNC('month', current_time::TIMESTAMP)::TIMESTAMPTZ;
free_tier_period_end := (free_tier_period_start + INTERVAL '1 month')::TIMESTAMPTZ;
-- Get subscription period
subscription_period_start := subscription_record.period_start;
subscription_period_end := subscription_record.period_end;
-- Look for existing free tier usage record
SELECT * INTO existing_usage_record
FROM user_usage
WHERE user_id = user_uuid
AND period_start = free_tier_period_start
AND period_end = free_tier_period_end;
-- If we found a free tier record and it's different from the subscription period
IF existing_usage_record IS NOT NULL AND
(existing_usage_record.period_start != subscription_period_start OR
existing_usage_record.period_end != subscription_period_end) THEN
-- Check if subscription period record already exists
IF EXISTS (
SELECT 1 FROM user_usage
WHERE user_id = user_uuid
AND period_start = subscription_period_start
AND period_end = subscription_period_end
) THEN
-- If subscription record exists, merge the usage and delete the free tier record
UPDATE user_usage
SET
advanced_prompts_used = advanced_prompts_used + existing_usage_record.advanced_prompts_used,
auto_prompts_used = auto_prompts_used + existing_usage_record.auto_prompts_used,
storage_used_gb = storage_used_gb + existing_usage_record.storage_used_gb,
custom_templates_created = custom_templates_created + existing_usage_record.custom_templates_created,
books_created = books_created + existing_usage_record.books_created,
updated_at = NOW()
WHERE user_id = user_uuid
AND period_start = subscription_period_start
AND period_end = subscription_period_end;
-- Delete the free tier record
DELETE FROM user_usage WHERE id = existing_usage_record.id;
ELSE
-- Update the existing free tier record to use subscription periods
UPDATE user_usage
SET
period_start = subscription_period_start,
period_end = subscription_period_end,
updated_at = NOW()
WHERE id = existing_usage_record.id;
END IF;
-- Log the migration
INSERT INTO usage_logs (user_id, feature_type, action, amount, metadata)
VALUES (user_uuid, 'advanced_prompts', 'migrate', 0,
jsonb_build_object(
'migration_type', 'free_to_subscription_period',
'old_period_start', free_tier_period_start,
'old_period_end', free_tier_period_end,
'new_period_start', subscription_period_start,
'new_period_end', subscription_period_end
));
END IF;
END;
$$;
-- Update get_or_create_current_usage to include migration logic
CREATE OR REPLACE FUNCTION get_or_create_current_usage(user_uuid UUID)
RETURNS user_usage
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public, pg_catalog, pg_temp
AS $$
DECLARE
usage_record user_usage;
period_info RECORD;
BEGIN
-- First, attempt to migrate any existing free tier usage to subscription period
PERFORM migrate_usage_to_subscription_period(user_uuid);
-- Get current period (after any migration)
SELECT * INTO period_info FROM get_current_usage_period(user_uuid);
-- Try to get existing usage record
SELECT * INTO usage_record
FROM user_usage
WHERE user_id = user_uuid
AND period_start = period_info.period_start
AND period_end = period_info.period_end;
-- Create if doesn't exist
IF usage_record IS NULL THEN
INSERT INTO user_usage (
user_id,
period_start,
period_end
) VALUES (
user_uuid,
period_info.period_start,
period_info.period_end
)
RETURNING * INTO usage_record;
END IF;
RETURN usage_record;
END;
$$;
-- Run a one-time cleanup for any existing duplicate records
-- This handles cases where users already have duplicate records from the bug
DO $$
DECLARE
user_record RECORD;
BEGIN
-- Find all users with active subscriptions
FOR user_record IN
SELECT DISTINCT user_id
FROM subscriptions
WHERE status IN ('active', 'trialing', 'past_due')
AND current_period_end > NOW()
LOOP
-- Run migration for each user
BEGIN
PERFORM migrate_usage_to_subscription_period(user_record.user_id);
EXCEPTION
WHEN OTHERS THEN
-- Log any errors but continue with other users
RAISE LOG 'Failed to migrate usage for user %: %', user_record.user_id, SQLERRM;
END;
END LOOP;
END $$;
-- Add helpful comments
COMMENT ON FUNCTION migrate_usage_to_subscription_period(UUID) IS 'Migrates existing free tier usage to subscription billing period when user upgrades - prevents duplicate records';
COMMENT ON FUNCTION get_or_create_current_usage(UUID) IS 'Gets existing usage record for current period or creates new one, with automatic migration for subscription upgrades';