Archive view creation code

This commit is contained in:
2025-11-05 15:26:08 +00:00
parent 630f541b4f
commit 750ff0d4ff
2 changed files with 120 additions and 0 deletions

View File

@@ -0,0 +1,110 @@
-- 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;
-- 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;

10
view_sql_archive/view.md Normal file
View File

@@ -0,0 +1,10 @@
To make handling the dashboard easier its good practice to create views that make the underlying data more accessible. Since data does not get updated that frequently we can also use materialized views to speed up query performance at the cost of storage.
## Schemas
public: Contains the data from the meta_api_grabber application. All ad accounts.
meta: Contains data from airbyte meta api connector. Unfortunatly somewhat bugged for insights on campaign and adset level. Aggregating data from the ads level is possible but much more cumbersome and error prone then querying the stuff directly. Thats why for now I'm continuing to use the meta_api_grabber
google: Will contain the data from google from the airbyte connector assuming we get access and the connector is good.