1+ -- API Usage Tracking Migration
2+ -- Adds daily API usage tracking for plan-based rate limiting
3+
4+ -- Add API usage columns to tenants table for current day tracking
5+ ALTER TABLE public .tenants
6+ ADD COLUMN IF NOT EXISTS api_requests_today INTEGER DEFAULT 0 ,
7+ ADD COLUMN IF NOT EXISTS api_requests_reset_at TIMESTAMPTZ DEFAULT (CURRENT_DATE + INTERVAL ' 1 day' );
8+
9+ -- Create API usage logs table for historical tracking
10+ CREATE TABLE IF NOT EXISTS public .api_usage_logs (
11+ id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
12+ tenant_id UUID NOT NULL REFERENCES public .tenants (id) ON DELETE CASCADE ,
13+ api_key_id UUID REFERENCES public .api_keys (id) ON DELETE SET NULL ,
14+ date DATE NOT NULL DEFAULT CURRENT_DATE ,
15+ requests_count INTEGER DEFAULT 0 ,
16+ created_at TIMESTAMPTZ DEFAULT NOW(),
17+ updated_at TIMESTAMPTZ DEFAULT NOW(),
18+ UNIQUE(tenant_id, date )
19+ );
20+
21+ -- Index for efficient lookups
22+ CREATE INDEX IF NOT EXISTS idx_api_usage_logs_tenant_date
23+ ON public .api_usage_logs (tenant_id, date DESC );
24+
25+ -- RLS policies for api_usage_logs
26+ ALTER TABLE public .api_usage_logs ENABLE ROW LEVEL SECURITY;
27+
28+ -- Users can view their own tenant's usage
29+ CREATE POLICY " Users can view own tenant API usage"
30+ ON public .api_usage_logs
31+ FOR SELECT
32+ USING (tenant_id = public .get_user_tenant_id ());
33+
34+ -- Service role can insert/update
35+ CREATE POLICY " Service role can manage API usage"
36+ ON public .api_usage_logs
37+ FOR ALL
38+ USING (auth .role () = ' service_role' );
39+
40+ -- Function to increment API usage (called from Edge Functions)
41+ CREATE OR REPLACE FUNCTION public .increment_api_usage(
42+ p_tenant_id UUID,
43+ p_api_key_id UUID DEFAULT NULL
44+ )
45+ RETURNS INTEGER
46+ LANGUAGE plpgsql
47+ SECURITY DEFINER
48+ SET search_path = public
49+ AS $$
50+ DECLARE
51+ v_today DATE := CURRENT_DATE ;
52+ v_new_count INTEGER ;
53+ BEGIN
54+ -- Upsert into daily usage log
55+ INSERT INTO public .api_usage_logs (tenant_id, api_key_id, date , requests_count)
56+ VALUES (p_tenant_id, p_api_key_id, v_today, 1 )
57+ ON CONFLICT (tenant_id, date )
58+ DO UPDATE SET
59+ requests_count = api_usage_logs .requests_count + 1 ,
60+ updated_at = NOW()
61+ RETURNING requests_count INTO v_new_count;
62+
63+ -- Also update tenant's current day counter
64+ UPDATE public .tenants
65+ SET
66+ api_requests_today = CASE
67+ WHEN api_requests_reset_at < NOW() THEN 1
68+ ELSE api_requests_today + 1
69+ END,
70+ api_requests_reset_at = CASE
71+ WHEN api_requests_reset_at < NOW() THEN CURRENT_DATE + INTERVAL ' 1 day'
72+ ELSE api_requests_reset_at
73+ END
74+ WHERE id = p_tenant_id;
75+
76+ RETURN v_new_count;
77+ END;
78+ $$;
79+
80+ -- Function to get current usage for a tenant
81+ CREATE OR REPLACE FUNCTION public .get_api_usage_stats(
82+ p_tenant_id UUID DEFAULT NULL
83+ )
84+ RETURNS TABLE(
85+ today_requests INTEGER ,
86+ this_month_requests BIGINT ,
87+ reset_at TIMESTAMPTZ ,
88+ daily_limit INTEGER
89+ )
90+ LANGUAGE plpgsql
91+ SECURITY DEFINER
92+ SET search_path = public
93+ AS $$
94+ DECLARE
95+ v_tenant_id UUID := COALESCE(p_tenant_id, public .get_user_tenant_id ());
96+ v_plan TEXT ;
97+ v_daily_limit INTEGER ;
98+ BEGIN
99+ -- Get tenant plan
100+ SELECT t .plan INTO v_plan
101+ FROM public .tenants t
102+ WHERE t .id = v_tenant_id;
103+
104+ -- Determine daily limit based on plan
105+ v_daily_limit := CASE v_plan
106+ WHEN ' free' THEN 100
107+ WHEN ' pro' THEN 1000
108+ WHEN ' premium' THEN 10000
109+ WHEN ' enterprise' THEN NULL -- unlimited
110+ ELSE 100
111+ END;
112+
113+ RETURN QUERY
114+ SELECT
115+ COALESCE(t .api_requests_today , 0 )::INTEGER as today_requests,
116+ COALESCE((
117+ SELECT SUM (requests_count)
118+ FROM api_usage_logs
119+ WHERE tenant_id = v_tenant_id
120+ AND date >= DATE_TRUNC(' month' , CURRENT_DATE )
121+ ), 0 )::BIGINT as this_month_requests,
122+ t .api_requests_reset_at as reset_at,
123+ v_daily_limit as daily_limit
124+ FROM public .tenants t
125+ WHERE t .id = v_tenant_id;
126+ END;
127+ $$;
128+
129+ -- Grant execute permissions
130+ GRANT EXECUTE ON FUNCTION public .increment_api_usage TO service_role;
131+ GRANT EXECUTE ON FUNCTION public .get_api_usage_stats TO authenticated;
0 commit comments