bookwiz.io / supabase / migrations / 025_fix_date_trunc_casting.sql
025_fix_date_trunc_casting.sql
Raw
-- Fix DATE_TRUNC casting issues in get_current_usage_period function
-- Error: function date_trunc(unknown, time with time zone) does not exist
-- Need to explicitly cast arguments to avoid type ambiguity

CREATE OR REPLACE FUNCTION get_current_usage_period(user_uuid UUID)
RETURNS TABLE (
    period_start TIMESTAMPTZ,
    period_end TIMESTAMPTZ
)
SECURITY DEFINER
SET search_path = public, pg_catalog, pg_temp
AS $$
DECLARE
    subscription_record RECORD;
    current_time TIMESTAMPTZ := NOW()::TIMESTAMPTZ;
BEGIN
    -- Get the user's active subscription with safe timestamp handling
    SELECT 
        id,
        user_id, 
        status,
        current_period_start,
        current_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;
    
    -- Check if we have a subscription and handle the timestamp conversion safely
    IF subscription_record IS NOT NULL AND subscription_record.current_period_end IS NOT NULL THEN
        -- Try to safely convert current_period_end to TIMESTAMPTZ
        BEGIN
            -- Check if this subscription is still active
            IF subscription_record.current_period_end::TIMESTAMPTZ > current_time THEN
                -- Return subscription period
                RETURN QUERY 
                SELECT 
                    subscription_record.current_period_start::TIMESTAMPTZ,
                    subscription_record.current_period_end::TIMESTAMPTZ;
                RETURN;
            END IF;
        EXCEPTION 
            WHEN OTHERS THEN
                -- If timestamp conversion fails, log and fall through to free tier
                RAISE LOG 'Failed to convert subscription period_end for user %: %', user_uuid, SQLERRM;
        END;
    END IF;
    
    -- Return current month for free tier (or when subscription processing fails)
    -- Use explicit text casting for DATE_TRUNC to avoid type ambiguity
    RETURN QUERY
    SELECT 
        DATE_TRUNC('month'::text, current_time)::TIMESTAMPTZ,
        (DATE_TRUNC('month'::text, current_time) + INTERVAL '1 month')::TIMESTAMPTZ;
END;
$$ LANGUAGE plpgsql;

-- Also update any other functions that might have similar DATE_TRUNC issues
-- Fix get_or_create_current_usage function to ensure type consistency
CREATE OR REPLACE FUNCTION get_or_create_current_usage(user_uuid UUID)
RETURNS user_usage
SECURITY DEFINER
SET search_path = public, pg_catalog, pg_temp
AS $$
DECLARE
    usage_record user_usage;
    period_info RECORD;
BEGIN
    -- Get current period
    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;
$$ LANGUAGE plpgsql;

-- Fix increment_usage function to ensure proper NOW() handling
CREATE OR REPLACE FUNCTION increment_usage(
    user_uuid UUID,
    feature_type_param TEXT,
    amount_param DECIMAL DEFAULT 1,
    metadata_param JSONB DEFAULT '{}'::jsonb,
    skip_limit_check BOOLEAN DEFAULT FALSE
)
RETURNS user_usage
SECURITY DEFINER
SET search_path = public, pg_catalog, pg_temp
AS $$
DECLARE
    usage_record user_usage;
    current_value DECIMAL;
    new_value DECIMAL;
    now_timestamp TIMESTAMPTZ := NOW()::TIMESTAMPTZ;
BEGIN
    -- Get or create current usage record
    SELECT * INTO usage_record FROM get_or_create_current_usage(user_uuid);
    
    -- Get current value for the feature type
    CASE feature_type_param
        WHEN 'advanced_prompts' THEN
            current_value := usage_record.advanced_prompts_used;
        WHEN 'auto_prompts' THEN
            current_value := usage_record.auto_prompts_used;
        WHEN 'storage_gb' THEN
            current_value := usage_record.storage_used_gb;
        WHEN 'custom_templates' THEN
            current_value := usage_record.custom_templates_created;
        WHEN 'books' THEN
            current_value := usage_record.books_created;
        ELSE
            RAISE EXCEPTION 'Invalid feature_type: %', feature_type_param;
    END CASE;
    
    new_value := current_value + amount_param;
    
    -- Prevent negative values (except for storage which can decrease)
    IF new_value < 0 AND feature_type_param != 'storage_gb' THEN
        RAISE EXCEPTION 'Cannot decrement % below zero', feature_type_param;
    END IF;
    
    -- Log the usage increment
    INSERT INTO usage_logs (user_id, feature_type, action, amount, metadata)
    VALUES (user_uuid, feature_type_param, 'increment', amount_param, metadata_param);
    
    -- Update the appropriate counter with explicit timestamp
    CASE feature_type_param
        WHEN 'advanced_prompts' THEN
            UPDATE user_usage 
            SET advanced_prompts_used = advanced_prompts_used + amount_param::INTEGER,
                updated_at = now_timestamp
            WHERE id = usage_record.id
            RETURNING * INTO usage_record;
            
        WHEN 'auto_prompts' THEN
            UPDATE user_usage 
            SET auto_prompts_used = auto_prompts_used + amount_param::INTEGER,
                updated_at = now_timestamp
            WHERE id = usage_record.id
            RETURNING * INTO usage_record;
            
        WHEN 'storage_gb' THEN
            UPDATE user_usage 
            SET storage_used_gb = storage_used_gb + amount_param,
                updated_at = now_timestamp
            WHERE id = usage_record.id
            RETURNING * INTO usage_record;
            
        WHEN 'custom_templates' THEN
            UPDATE user_usage 
            SET custom_templates_created = custom_templates_created + amount_param::INTEGER,
                updated_at = now_timestamp
            WHERE id = usage_record.id
            RETURNING * INTO usage_record;
            
        WHEN 'books' THEN
            UPDATE user_usage 
            SET books_created = books_created + amount_param::INTEGER,
                updated_at = now_timestamp
            WHERE id = usage_record.id
            RETURNING * INTO usage_record;
            
        ELSE
            RAISE EXCEPTION 'Invalid feature_type: %', feature_type_param;
    END CASE;
    
    RETURN usage_record;
END;
$$ LANGUAGE plpgsql;

-- Add helpful comments
COMMENT ON FUNCTION get_current_usage_period(UUID) IS 'Fixed DATE_TRUNC casting issues with explicit text casting';
COMMENT ON FUNCTION increment_usage(UUID, TEXT, DECIMAL, JSONB, BOOLEAN) IS 'Fixed timestamp handling with explicit TIMESTAMPTZ casting';