Skip to content

Commit

Permalink
feat: Add analytics views
Browse files Browse the repository at this point in the history
  • Loading branch information
storm1729 committed Dec 22, 2024
1 parent afcc177 commit 0008e65
Show file tree
Hide file tree
Showing 4 changed files with 182 additions and 0 deletions.
5 changes: 5 additions & 0 deletions supabase/migrations/20241222142037_add_indexes.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
-- Add indexes for commonly joined/filtered columns
CREATE INDEX IF NOT EXISTS idx_calls_created_at ON calls(created_at);
CREATE INDEX IF NOT EXISTS idx_calls_user_id_created_at ON calls(user_id, created_at);
CREATE INDEX IF NOT EXISTS idx_calls_endpoint ON calls(endpoint);
CREATE INDEX IF NOT EXISTS idx_subscriptions_user_id_status ON subscriptions(user_id, status);
41 changes: 41 additions & 0 deletions supabase/migrations/20241222142132_improve_bulk_jobs_info.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
CREATE OR REPLACE VIEW bulk_jobs_info
WITH (security_invoker = TRUE)
AS
WITH call_stats AS (
SELECT
be.bulk_job_id,
COUNT(DISTINCT be.id) AS verified,
SUM(CASE WHEN c.is_reachable = 'risky' THEN 1 ELSE 0 END) as risky,
SUM(CASE WHEN c.is_reachable = 'invalid' THEN 1 ELSE 0 END) as invalid,
SUM(CASE WHEN c.is_reachable = 'unknown' THEN 1 ELSE 0 END) as unknown,
SUM(CASE WHEN c.is_reachable = 'safe' THEN 1 ELSE 0 END) as safe,
MAX(c.created_at) as last_call_time
FROM bulk_emails be
LEFT JOIN calls c ON be.id = c.bulk_email_id
GROUP BY be.bulk_job_id
)
SELECT
bj.id AS bulk_job_id,
bj.user_id,
bj.created_at,
COUNT(DISTINCT be.id) AS number_of_emails,
COALESCE(cs.verified, 0) AS verified,
COALESCE(cs.risky, 0) AS risky,
COALESCE(cs.invalid, 0) AS invalid,
COALESCE(cs.unknown, 0) AS unknown,
COALESCE(cs.safe, 0) AS safe,
cs.last_call_time
FROM
bulk_jobs bj
LEFT JOIN bulk_emails be ON bj.id = be.bulk_job_id
LEFT JOIN call_stats cs ON cs.bulk_job_id = bj.id
GROUP BY
bj.id,
cs.verified,
cs.risky,
cs.invalid,
cs.unknown,
cs.safe,
cs.last_call_time
ORDER BY
bj.created_at DESC;
55 changes: 55 additions & 0 deletions supabase/migrations/20241222142151_improve_sub_and_calls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
CREATE OR REPLACE VIEW sub_and_calls
WITH (security_invoker = TRUE)
AS
WITH filtered_calls AS (
SELECT
user_id,
id,
created_at,
endpoint
FROM public.calls
WHERE created_at >= (NOW() - INTERVAL '1 month')
)
SELECT
u.id AS user_id,
s.id AS subscription_id,
s.status,
s.current_period_start,
s.current_period_end,
s.cancel_at,
COUNT(CASE WHEN c.endpoint != '/v1/commercial_license_trial' THEN c.id END) AS number_of_calls,
pro.id AS product_id
FROM
public.users u
LEFT JOIN public.subscriptions s ON u.id = s.user_id AND s.status = 'active'
LEFT JOIN public.prices pri ON pri.id = s.price_id
LEFT JOIN public.products pro ON pro.id = pri.product_id
LEFT JOIN filtered_calls c ON u.id = c.user_id AND (
(
s.current_period_start IS NOT NULL AND
s.current_period_end IS NOT NULL AND
c.created_at BETWEEN s.current_period_start AND s.current_period_end
) OR (
s.current_period_start IS NULL
)
)
GROUP BY
u.id,
s.id,
s.status,
s.current_period_start,
s.current_period_end,
s.cancel_at,
pro.id;

-- View to analyze how users heard about the service in the last 3 months
CREATE OR REPLACE VIEW analytics_acquisition_channels_past_3mo
WITH (security_invoker = TRUE) AS
SELECT
raw_user_meta_data->>'heardFrom' as heard_from,
COUNT(*) AS user_count
FROM auth.users
WHERE raw_user_meta_data->>'heardFrom' IS NOT NULL
AND created_at >= NOW() - INTERVAL '3 months'
GROUP BY heard_from
ORDER BY user_count DESC;
81 changes: 81 additions & 0 deletions supabase/migrations/20241222143000_analytics_views.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,81 @@
-- View for unknown domains in the last 3 months
CREATE OR REPLACE VIEW analytics_unknown_domains_past_3mo
WITH (security_invoker = on) AS
SELECT
domain,
COUNT(*) as occurrences
FROM calls
WHERE
is_reachable = 'unknown'
AND created_at >= NOW() - INTERVAL '3 months'
AND domain IS NOT NULL
GROUP BY domain
ORDER BY occurrences DESC;

-- View for monthly email verification results
CREATE OR REPLACE VIEW analytics_monthly_results
WITH (security_invoker = on) AS
SELECT
DATE_TRUNC('month', created_at) as month,
SUM(CASE WHEN is_reachable = 'safe' THEN 1 ELSE 0 END) as safe_count,
SUM(CASE WHEN is_reachable = 'risky' THEN 1 ELSE 0 END) as risky_count,
SUM(CASE WHEN is_reachable = 'unknown' THEN 1 ELSE 0 END) as unknown_count,
SUM(CASE WHEN is_reachable = 'invalid' THEN 1 ELSE 0 END) as invalid_count
FROM calls
GROUP BY month
ORDER BY month DESC;

-- View for monthly unique users using commercial license endpoint
CREATE OR REPLACE VIEW analytics_commercial_license_usage
WITH (security_invoker = on) AS
SELECT
DATE_TRUNC('month', created_at) as month,
COUNT(DISTINCT user_id) as trial_users
FROM calls
WHERE endpoint = '/v1/commercial_license_trial'
GROUP BY month
ORDER BY month DESC;

-- View for commercial license users in the past month
CREATE OR REPLACE VIEW analytics_commercial_license_users_past_month
WITH (security_invoker = on) AS
SELECT
u.id AS user_id,
u.email,
u.created_at AS registration_date,
COUNT(c.id) AS call_count
FROM auth.users u
JOIN calls c ON u.id = c.user_id
WHERE c.endpoint = '/v1/commercial_license_trial'
AND c.created_at >= NOW() - INTERVAL '1 month'
GROUP BY u.id, u.email, u.created_at
ORDER BY call_count DESC;

-- View for SaaS users with active subscriptions
CREATE VIEW analytics_saas_users
WITH (security_invoker = on) AS
SELECT
u.id AS user_id,
u.email,
u.created_at AS sign_up_date,
s.id AS subscription_id,
COUNT(c.id) AS email_count
FROM auth.users u
JOIN subscriptions s ON u.id = s.user_id
JOIN calls c ON u.id = c.user_id
WHERE s.status = 'active'
AND c.created_at >= NOW() - INTERVAL '1 month'
GROUP BY u.id, u.email, u.created_at, s.id
ORDER BY email_count DESC;

-- View to analyze how users heard about the service in the last 3 months
CREATE OR REPLACE VIEW analytics_acquisition_channels_past_3mo
WITH (security_invoker = TRUE) AS
SELECT
raw_user_meta_data->>'heardFrom' as heard_from,
COUNT(*) AS user_count
FROM auth.users
WHERE raw_user_meta_data->>'heardFrom' IS NOT NULL
AND created_at >= NOW() - INTERVAL '3 months'
GROUP BY heard_from
ORDER BY user_count DESC;

0 comments on commit 0008e65

Please sign in to comment.