151 lines
4.2 KiB
SQL
151 lines
4.2 KiB
SQL
-- Auto refreshes when new entries get added. New things can be extracted from actions if necessary.
|
|
|
|
CREATE MATERIALIZED VIEW adset_insights_flattened AS
|
|
SELECT
|
|
time,
|
|
adset_id,
|
|
campaign_id,
|
|
account_id,
|
|
impressions,
|
|
clicks,
|
|
spend,
|
|
reach,
|
|
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 adset_insights;
|
|
|
|
-- Add indexes for common query patterns
|
|
|
|
CREATE INDEX idx_adset_insights_flat_campaign ON adset_insights_flattened(campaign_id);
|
|
CREATE INDEX idx_adset_insights_flat_date ON adset_insights_flattened(date_start, date_stop);
|
|
|
|
|
|
CREATE UNIQUE INDEX idx_adset_insights_flat_unique ON adset_insights_flattened(time, adset_id);
|
|
REFRESH MATERIALIZED VIEW CONCURRENTLY adset_insights_flattened;
|
|
|
|
|
|
|
|
--- same or atleast very similar for account_insights
|
|
|
|
CREATE MATERIALIZED VIEW account_insights_flattened AS
|
|
SELECT
|
|
time,
|
|
account_id,
|
|
impressions,
|
|
clicks,
|
|
spend,
|
|
reach,
|
|
frequency,
|
|
ctr,
|
|
cpc,
|
|
cpm,
|
|
cpp,
|
|
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,
|
|
(SELECT (value->>'value')::numeric
|
|
FROM jsonb_array_elements(cost_per_action_type)
|
|
WHERE value->>'action_type' = 'link_click') AS cost_per_link_click,
|
|
(SELECT (value->>'value')::numeric
|
|
FROM jsonb_array_elements(cost_per_action_type)
|
|
WHERE value->>'action_type' = 'landing_page_view') AS cost_per_landing_page_view,
|
|
(SELECT (value->>'value')::numeric
|
|
FROM jsonb_array_elements(cost_per_action_type)
|
|
WHERE value->>'action_type' = 'lead') AS cost_per_lead
|
|
|
|
FROM account_insights;
|
|
|
|
|
|
CREATE INDEX idx_account_insights_flat_date ON account_insights_flattened(date_start, date_stop);
|
|
|
|
|
|
CREATE UNIQUE INDEX idx_account_insights_flat_unique ON account_insights_flattened(time, account_id);
|
|
REFRESH MATERIALIZED VIEW CONCURRENTLY account_insights_flattened;
|
|
|
|
|
|
--- campaign insights
|
|
|
|
CREATE MATERIALIZED VIEW campaign_insights_flattened AS
|
|
SELECT
|
|
time,
|
|
account_id,
|
|
campaign_id,
|
|
impressions,
|
|
clicks,
|
|
spend,
|
|
reach,
|
|
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;
|
|
|
|
CREATE INDEX idx_campaign_insights_flat_date ON campaign_insights_flattened(date_start, date_stop);
|
|
|
|
CREATE UNIQUE INDEX idx_campaign_insights_flat_unique ON campaign_insights_flattened(time, campaign_id);
|
|
|
|
REFRESH MATERIALIZED VIEW CONCURRENTLY campaign_insights_flattened;
|
|
|
|
|
|
-- permissinos
|
|
|
|
-- Grant SELECT on the existing materialized view
|
|
GRANT SELECT ON account_insights_flattened TO grafana;
|
|
|
|
GRANT SELECT ON campaign_insights_flattened TO grafana;
|
|
|
|
GRANT SELECT ON adset_insights_flattened TO grafana;
|
|
|
|
|
|
-- Grant SELECT on all existing tables and views in the schema
|
|
GRANT SELECT ON ALL TABLES IN SCHEMA public TO grafana;
|
|
|
|
-- Grant SELECT on all future tables and views in the schema
|
|
ALTER DEFAULT PRIVILEGES IN SCHEMA public
|
|
GRANT SELECT ON TABLES TO grafana;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|