Updated view queries
This commit is contained in:
@@ -93,6 +93,8 @@ class ViewManager:
|
||||
"account_insights_flattened",
|
||||
"campaign_insights_flattened",
|
||||
"campaign_insights_by_country_flattened",
|
||||
#"campaign_insights_by_device_flattened",
|
||||
#"campaign_insights_by_gender_flattened",
|
||||
]
|
||||
|
||||
async with self.pool.acquire() as conn:
|
||||
|
||||
20
src/meta_api_grabber/views/account_insights_by_device.sql
Normal file
20
src/meta_api_grabber/views/account_insights_by_device.sql
Normal file
@@ -0,0 +1,20 @@
|
||||
--- account insights by gender
|
||||
|
||||
|
||||
DROP VIEW IF EXISTS account_insights_by_device CASCADE;
|
||||
|
||||
CREATE VIEW account_insights_by_device AS
|
||||
SELECT
|
||||
time,
|
||||
account_id,
|
||||
device_platform,
|
||||
SUM(impressions) AS impressions,
|
||||
SUM(clicks) AS clicks,
|
||||
SUM(spend) AS spend,
|
||||
SUM(link_click) AS link_click,
|
||||
SUM(landing_page_view) AS landing_page_view,
|
||||
SUM(lead) AS lead
|
||||
FROM campaign_insights_by_device_flattened
|
||||
GROUP BY time, account_id, device_platform;
|
||||
|
||||
|
||||
53
src/meta_api_grabber/views/account_insights_by_gender.sql
Normal file
53
src/meta_api_grabber/views/account_insights_by_gender.sql
Normal file
@@ -0,0 +1,53 @@
|
||||
|
||||
|
||||
|
||||
DROP VIEW IF EXISTS account_insights_by_gender CASCADE;
|
||||
|
||||
CREATE VIEW account_insights_by_gender AS
|
||||
SELECT
|
||||
time,
|
||||
account_id,
|
||||
gender,
|
||||
SUM(impressions) AS impressions,
|
||||
SUM(clicks) AS clicks,
|
||||
SUM(spend) AS spend,
|
||||
SUM(link_click) AS link_click,
|
||||
SUM(landing_page_view) AS landing_page_view,
|
||||
SUM(lead) AS lead
|
||||
FROM campaign_insights_by_gender
|
||||
GROUP BY time, account_id, gender;
|
||||
|
||||
|
||||
DROP VIEW IF EXISTS account_insights_by_age CASCADE;
|
||||
|
||||
CREATE VIEW account_insights_by_age AS
|
||||
SELECT
|
||||
time,
|
||||
account_id,
|
||||
age,
|
||||
SUM(impressions) AS impressions,
|
||||
SUM(clicks) AS clicks,
|
||||
SUM(spend) AS spend,
|
||||
SUM(link_click) AS link_click,
|
||||
SUM(landing_page_view) AS landing_page_view,
|
||||
SUM(lead) AS lead
|
||||
FROM campaign_insights_by_age
|
||||
GROUP BY time, account_id, age;
|
||||
|
||||
DROP VIEW IF EXISTS account_insights_by_gender_and_age CASCADE;
|
||||
|
||||
CREATE VIEW account_insights_by_gender_and_age AS
|
||||
SELECT
|
||||
time,
|
||||
account_id,
|
||||
gender,
|
||||
age,
|
||||
SUM(impressions) AS impressions,
|
||||
SUM(clicks) AS clicks,
|
||||
SUM(spend) AS spend,
|
||||
SUM(link_click) AS link_click,
|
||||
SUM(landing_page_view) AS landing_page_view,
|
||||
SUM(lead) AS lead
|
||||
FROM campaign_insights_by_gender_and_age
|
||||
GROUP BY time, account_id, age, gender;
|
||||
|
||||
55
src/meta_api_grabber/views/account_insights_google.sql
Normal file
55
src/meta_api_grabber/views/account_insights_google.sql
Normal file
@@ -0,0 +1,55 @@
|
||||
DROP VIEW IF EXISTS g_account_insights CASCADE;
|
||||
CREATE VIEW g_account_insights AS
|
||||
SELECT
|
||||
time,
|
||||
account_id,
|
||||
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,
|
||||
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
|
||||
) base;
|
||||
@@ -3,9 +3,8 @@
|
||||
DROP MATERIALIZED VIEW IF EXISTS campaign_insights_flattened CASCADE;
|
||||
|
||||
CREATE MATERIALIZED VIEW campaign_insights_flattened AS
|
||||
SELECT
|
||||
time,
|
||||
account_id,
|
||||
SELECT date_start AS "time",
|
||||
concat('act_', account_id) AS account_id,
|
||||
campaign_id,
|
||||
impressions,
|
||||
clicks,
|
||||
@@ -14,22 +13,18 @@ SELECT
|
||||
ctr,
|
||||
cpc,
|
||||
cpm,
|
||||
date_preset,
|
||||
date_start,
|
||||
date_stop,
|
||||
fetched_at,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'link_click') AS link_click,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'landing_page_view') AS landing_page_view,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'lead') AS lead
|
||||
|
||||
|
||||
FROM campaign_insights;
|
||||
( SELECT (jsonb_array_elements.value ->> 'value'::text)::numeric AS "numeric"
|
||||
FROM jsonb_array_elements(customcampaign_insights.actions) jsonb_array_elements(value)
|
||||
WHERE (jsonb_array_elements.value ->> 'action_type'::text) = 'link_click'::text) AS link_click,
|
||||
( SELECT (jsonb_array_elements.value ->> 'value'::text)::numeric AS "numeric"
|
||||
FROM jsonb_array_elements(customcampaign_insights.actions) jsonb_array_elements(value)
|
||||
WHERE (jsonb_array_elements.value ->> 'action_type'::text) = 'landing_page_view'::text) AS landing_page_view,
|
||||
( SELECT (jsonb_array_elements.value ->> 'value'::text)::numeric AS "numeric"
|
||||
FROM jsonb_array_elements(customcampaign_insights.actions) jsonb_array_elements(value)
|
||||
WHERE (jsonb_array_elements.value ->> 'action_type'::text) = 'lead'::text) AS lead
|
||||
FROM meta.customcampaign_insights;
|
||||
|
||||
CREATE INDEX idx_campaign_insights_flat_date ON campaign_insights_flattened(date_start, date_stop);
|
||||
|
||||
|
||||
@@ -3,22 +3,20 @@
|
||||
DROP MATERIALIZED VIEW IF EXISTS campaign_insights_by_country_flattened CASCADE;
|
||||
|
||||
CREATE MATERIALIZED VIEW campaign_insights_by_country_flattened AS
|
||||
SELECT
|
||||
time,
|
||||
account_id,
|
||||
SELECT date_start AS "time",
|
||||
concat('act_', account_id) AS account_id,
|
||||
campaign_id,
|
||||
country,
|
||||
impressions,
|
||||
clicks,
|
||||
spend,
|
||||
reach,
|
||||
frequency,
|
||||
ctr,
|
||||
cpc,
|
||||
cpm,
|
||||
date_preset,
|
||||
date_start,
|
||||
date_stop,
|
||||
fetched_at,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'link_click') AS link_click,
|
||||
@@ -29,7 +27,7 @@ SELECT
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'lead') AS lead
|
||||
|
||||
FROM campaign_insights_by_country;
|
||||
FROM meta.custom_campaign_country;
|
||||
|
||||
CREATE INDEX idx_campaign_insights_by_country_flat_date ON campaign_insights_by_country_flattened(date_start, date_stop);
|
||||
|
||||
|
||||
32
src/meta_api_grabber/views/campaign_insights_by_device.sql
Normal file
32
src/meta_api_grabber/views/campaign_insights_by_device.sql
Normal file
@@ -0,0 +1,32 @@
|
||||
--- campaign insights by device
|
||||
|
||||
DROP MATERIALIZED VIEW IF EXISTS campaign_insights_by_device_flattened CASCADE;
|
||||
|
||||
CREATE MATERIALIZED VIEW campaign_insights_by_device_flattened AS
|
||||
SELECT date_start AS "time",
|
||||
concat('act_', account_id) AS account_id,
|
||||
campaign_id,
|
||||
device_platform,
|
||||
impressions,
|
||||
clicks,
|
||||
spend,
|
||||
reach,
|
||||
frequency,
|
||||
date_start,
|
||||
date_stop,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'link_click') AS link_click,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'landing_page_view') AS landing_page_view,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'lead') AS lead
|
||||
|
||||
FROM meta.custom_campaign_device;
|
||||
|
||||
CREATE INDEX idx_campaign_insights_by_device_flat_date ON campaign_insights_by_device_flattened(date_start, date_stop);
|
||||
|
||||
CREATE UNIQUE INDEX idx_campaign_insights_by_device_flat_unique ON campaign_insights_by_device_flattened(time, campaign_id, device_platform);
|
||||
REFRESH MATERIALIZED VIEW CONCURRENTLY campaign_insights_by_device_flattened;
|
||||
71
src/meta_api_grabber/views/campaign_insights_by_gender.sql
Normal file
71
src/meta_api_grabber/views/campaign_insights_by_gender.sql
Normal file
@@ -0,0 +1,71 @@
|
||||
--- campaign insights by country
|
||||
|
||||
DROP MATERIALIZED VIEW IF EXISTS campaign_insights_by_gender_and_age CASCADE;
|
||||
|
||||
CREATE MATERIALIZED VIEW campaign_insights_by_gender_and_age AS
|
||||
SELECT date_start AS "time",
|
||||
concat('act_', account_id) AS account_id,
|
||||
campaign_id,
|
||||
gender,
|
||||
age,
|
||||
impressions,
|
||||
clicks,
|
||||
spend,
|
||||
reach,
|
||||
frequency,
|
||||
ctr,
|
||||
cpc,
|
||||
cpm,
|
||||
date_start,
|
||||
date_stop,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'link_click') AS link_click,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'landing_page_view') AS landing_page_view,
|
||||
(SELECT (value->>'value')::numeric
|
||||
FROM jsonb_array_elements(actions)
|
||||
WHERE value->>'action_type' = 'lead') AS lead
|
||||
|
||||
FROM meta.custom_campaign_gender;
|
||||
|
||||
CREATE INDEX idx_campaign_insights_by_gender_and_age_date ON campaign_insights_by_gender_and_age(date_start, date_stop);
|
||||
|
||||
CREATE UNIQUE INDEX idx_campaign_insights_by_gender_and_age_unique ON campaign_insights_by_gender_and_age(time, campaign_id, gender, age);
|
||||
REFRESH MATERIALIZED VIEW CONCURRENTLY campaign_insights_by_gender_and_age;
|
||||
|
||||
|
||||
DROP VIEW IF EXISTS campaign_insights_by_gender CASCADE;
|
||||
|
||||
create view campaign_insights_by_gender as
|
||||
Select time,
|
||||
sum(clicks) as clicks,
|
||||
sum(link_click) as link_click,
|
||||
sum(lead) as lead,
|
||||
sum(landing_page_view) as landing_page_view,
|
||||
sum(spend) as spend,
|
||||
sum(reach) as reach,
|
||||
sum(impressions) as impressions,
|
||||
gender,
|
||||
campaign_id,
|
||||
account_id
|
||||
from campaign_insights_by_gender_and_age
|
||||
group by time, gender, account_id, campaign_id, date_start, date_stop;
|
||||
|
||||
DROP VIEW IF EXISTS campaign_insights_by_age CASCADE;
|
||||
|
||||
create view campaign_insights_by_age as
|
||||
Select time,
|
||||
sum(clicks) as clicks,
|
||||
sum(link_click) as link_click,
|
||||
sum(lead) as lead,
|
||||
sum(landing_page_view) as landing_page_view,
|
||||
sum(spend) as spend,
|
||||
sum(reach) as reach,
|
||||
sum(impressions) as impressions,
|
||||
age,
|
||||
campaign_id,
|
||||
account_id
|
||||
from campaign_insights_by_gender_and_age
|
||||
group by time, age, account_id, campaign_id, date_start, date_stop;
|
||||
Reference in New Issue
Block a user