Create device specific version of account_insights

This commit is contained in:
2025-11-13 19:35:14 +00:00
parent 4778d2043b
commit 112755224f

View File

@@ -448,5 +448,65 @@ FROM (
DROP VIEW IF EXISTS g_account_insights_device CASCADE;
CREATE VIEW g_account_insights_device AS
SELECT
time,
account_id,
device,
clicks,
impressions,
interactions,
cost_micros,
cost_micros / 1000000.0 as cost,
leads,
engagements,
customer_currency_code,
account_name,
-- CTR (Click-Through Rate)
(clicks::numeric / impressions_nz) * 100 as ctr,
-- CPM (Cost Per Mille) in micros and standard units
(cost_micros::numeric / impressions_nz) * 1000 as cpm_micros,
(cost_micros::numeric / impressions_nz) * 1000 / 1000000.0 as cpm,
-- CPC (Cost Per Click) in micros and standard units
cost_micros::numeric / clicks_nz as cpc_micros,
cost_micros::numeric / clicks_nz / 1000000.0 as cpc,
-- CPL (Cost Per Lead) in micros and standard units
cost_micros::numeric / leads_nz as cpl_micros,
cost_micros::numeric / leads_nz / 1000000.0 as cpl,
-- Conversion Rate
(leads::numeric / clicks_nz) * 100 as conversion_rate,
-- Engagement Rate
(engagements::numeric / impressions_nz) * 100 as engagement_rate
FROM (
SELECT
segments_date as time,
customer_id as account_id,
segments_device as device,
sum(metrics_clicks) as clicks,
sum(metrics_impressions) as impressions,
sum(metrics_interactions) as interactions,
sum(metrics_cost_micros) as cost_micros,
sum(metrics_conversions) as leads,
sum(metrics_engagements) as engagements,
customer_currency_code,
customer_descriptive_name as account_name,
-- Null-safe denominators
NULLIF(sum(metrics_clicks), 0) as clicks_nz,
NULLIF(sum(metrics_impressions), 0) as impressions_nz,
NULLIF(sum(metrics_conversions), 0) as leads_nz
FROM google.account_performance_report
GROUP BY account_id, time, customer_currency_code, account_name, segments_device
) base;