bookwiz.io / supabase / migrations / 057_rename_usage_columns.sql
057_rename_usage_columns.sql
Raw
-- Migration to rename usage columns from advanced/auto to smart/fast
-- This aligns the database schema with our new AI model naming convention

-- Rename columns in user_usage table
ALTER TABLE user_usage 
RENAME COLUMN advanced_prompts_used TO smart_prompts_used;

ALTER TABLE user_usage 
RENAME COLUMN auto_prompts_used TO fast_prompts_used;

-- Drop the old check constraint first
ALTER TABLE usage_logs 
DROP CONSTRAINT usage_logs_feature_type_check;

-- Update existing usage_logs records to use new feature types
UPDATE usage_logs 
SET feature_type = 'smart_prompts' 
WHERE feature_type = 'advanced_prompts';

UPDATE usage_logs 
SET feature_type = 'fast_prompts' 
WHERE feature_type = 'auto_prompts';

-- Add the new check constraint
ALTER TABLE usage_logs 
ADD CONSTRAINT usage_logs_feature_type_check 
CHECK (feature_type IN ('smart_prompts', 'fast_prompts', 'storage_gb', 'custom_templates', 'books'));

-- Drop and recreate function that references the old column names
DROP FUNCTION IF EXISTS increment_usage(UUID, TEXT, DECIMAL);

CREATE OR REPLACE FUNCTION increment_usage(
    user_uuid UUID,
    feature_type TEXT,
    amount DECIMAL DEFAULT 1
) RETURNS JSON AS $$
DECLARE
    usage_record user_usage%ROWTYPE;
    current_value DECIMAL;
    result JSON;
BEGIN
    -- Get or create current usage record
    usage_record := get_or_create_current_usage(user_uuid);
    
    -- Update the appropriate counter based on feature type
    CASE feature_type
        WHEN 'smart_prompts' THEN 
            current_value := usage_record.smart_prompts_used;
            UPDATE user_usage 
            SET smart_prompts_used = smart_prompts_used + amount,
                updated_at = NOW()
            WHERE id = usage_record.id;
        WHEN 'fast_prompts' THEN 
            current_value := usage_record.fast_prompts_used;
            UPDATE user_usage 
            SET fast_prompts_used = fast_prompts_used + amount,
                updated_at = NOW()
            WHERE id = usage_record.id;
        WHEN 'storage_gb' THEN 
            current_value := usage_record.storage_used_gb;
            UPDATE user_usage 
            SET storage_used_gb = storage_used_gb + amount,
                updated_at = NOW()
            WHERE id = usage_record.id;
        WHEN 'custom_templates' THEN 
            current_value := usage_record.custom_templates_created;
            UPDATE user_usage 
            SET custom_templates_created = custom_templates_created + amount,
                updated_at = NOW()
            WHERE id = usage_record.id;
        WHEN 'books' THEN 
            current_value := usage_record.books_created;
            UPDATE user_usage 
            SET books_created = books_created + amount,
                updated_at = NOW()
            WHERE id = usage_record.id;
        ELSE
            RAISE EXCEPTION 'Invalid feature_type: %', feature_type;
    END CASE;
    
    -- Log the usage increment
    INSERT INTO usage_logs (user_id, feature_type, action, amount, metadata)
    VALUES (user_uuid, feature_type, 'increment', amount, json_build_object(
        'previous_value', current_value,
        'new_value', current_value + amount
    ));
    
    -- Return success response
    SELECT json_build_object(
        'success', true,
        'previous_value', current_value,
        'new_value', current_value + amount,
        'feature_type', feature_type
    ) INTO result;
    
    RETURN result;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;

-- Update the get_user_usage_stats function to use new column names
CREATE OR REPLACE FUNCTION get_user_usage_stats(p_user_id UUID)
RETURNS JSON
SECURITY DEFINER
SET search_path = public, pg_catalog, pg_temp
AS $$
DECLARE
    result JSON;
    current_usage_record user_usage;
BEGIN
    -- Get current usage record (which the increment_usage function updates)
    SELECT * INTO current_usage_record 
    FROM get_or_create_current_usage(p_user_id);
    
    -- Build result using the same data that limits are enforced against
    SELECT json_build_object(
        'current_month', json_build_object(
            'smart', json_build_object(
                'count', current_usage_record.smart_prompts_used,
                'tokens', 0, -- Token tracking is in ai_usage table, not user_usage
                'cost', 0
            ),
            'fast', json_build_object(
                'count', current_usage_record.fast_prompts_used,
                'tokens', 0, -- Token tracking is in ai_usage table, not user_usage  
                'cost', 0
            )
        ),
        'total_books', (
            SELECT COUNT(*) FROM books WHERE user_id = p_user_id
        ),
        'total_words', (
            SELECT COALESCE(SUM(word_count), 0) FROM books WHERE user_id = p_user_id
        )
    ) INTO result;
    
    RETURN result;
END;
$$ LANGUAGE plpgsql;

-- Update the can_user_make_request function to use new column names
CREATE OR REPLACE FUNCTION can_user_make_request(
    p_user_id UUID, 
    p_tier TEXT, 
    p_limit INTEGER
) RETURNS JSON
SECURITY DEFINER
SET search_path = public, pg_catalog, pg_temp
AS $$
DECLARE
    current_usage INTEGER := 0;
    current_usage_record user_usage;
    result JSON;
BEGIN
    -- Get current usage record (same source as increment_usage uses)
    SELECT * INTO current_usage_record 
    FROM get_or_create_current_usage(p_user_id);
    
    -- Get current usage for the specific tier
    CASE p_tier
        WHEN 'smart' THEN
            current_usage := current_usage_record.smart_prompts_used;
        WHEN 'fast' THEN
            current_usage := current_usage_record.fast_prompts_used;
        ELSE
            current_usage := 0;
    END CASE;
    
    -- Return usage info and whether request can proceed
    SELECT json_build_object(
        'can_proceed', (current_usage < p_limit OR p_limit = 0),
        'current_usage', current_usage,
        'limit', p_limit,
        'remaining', GREATEST(0, p_limit - current_usage)
    ) INTO result;
    
    RETURN result;
END;
$$ LANGUAGE plpgsql;

-- Add helpful comments
COMMENT ON FUNCTION get_user_usage_stats(UUID) IS 'Updated to use smart/fast column names for consistency with new AI model naming';
COMMENT ON FUNCTION can_user_make_request(UUID, TEXT, INTEGER) IS 'Updated to use smart/fast column names for consistency with new AI model naming';