From 4233d4f1d66b8863b9401ce49f128c59f4abc198 Mon Sep 17 00:00:00 2001 From: Joseph Shearer Date: Fri, 25 Aug 2023 15:32:12 -0400 Subject: [PATCH 1/8] feature: Implement `billing_historicals` and `internal.freeze_billing_month(billed_month timestamptz)` Also update `billing_report_202308()` to allow callers with `BYPASSRLS` set to generate the billing report for any tenant. --- supabase/migrations/21_billing_v2.sql | 11 +- .../migrations/24_billing_historicals.sql | 87 +++++++ supabase/pending/billing_historicals.sql | 234 ++++++++++++++++++ 3 files changed, 331 insertions(+), 1 deletion(-) create mode 100644 supabase/migrations/24_billing_historicals.sql create mode 100644 supabase/pending/billing_historicals.sql diff --git a/supabase/migrations/21_billing_v2.sql b/supabase/migrations/21_billing_v2.sql index d163c95bb0..74cc47e4ce 100644 --- a/supabase/migrations/21_billing_v2.sql +++ b/supabase/migrations/21_billing_v2.sql @@ -148,6 +148,9 @@ create function billing_report_202308(billed_prefix catalog_prefix, billed_month returns jsonb as $$ #variable_conflict use_variable declare + -- Auth checks + has_admin_grant boolean; + has_bypassrls boolean; -- Retrieved from tenants table. data_tiers integer[]; usage_tiers integer[]; @@ -174,7 +177,13 @@ begin -- Verify that the user has an admin grant for the requested `billed_prefix`. perform 1 from auth_roles('admin') as r where billed_prefix ^@ r.role_prefix; - if not found then + has_admin_grant = found; + + -- Check whether user has bypassrls flag + perform 1 from pg_roles where rolname = session_user and rolbypassrls = true; + has_bypassrls = found; + + if not has_bypassrls and not found then -- errcode 28000 causes PostgREST to return an HTTP 403 -- see: https://www.postgresql.org/docs/current/errcodes-appendix.html -- and: https://postgrest.org/en/stable/errors.html#status-codes diff --git a/supabase/migrations/24_billing_historicals.sql b/supabase/migrations/24_billing_historicals.sql new file mode 100644 index 0000000000..da1647f01e --- /dev/null +++ b/supabase/migrations/24_billing_historicals.sql @@ -0,0 +1,87 @@ + +-- Always use a transaction, y'all. +begin; + +-- Historical record of tenant billing statements. This structure +-- comes from the return value of `billing_report_202308`. +create table billing_historicals ( + tenant catalog_tenant not null, + billed_month timestamptz not null, + line_items jsonb not null, + processed_data_gb numeric not null, + recurring_fee integer not null, + subtotal integer not null, + task_usage_hours numeric not null + + check (date_trunc('month', billed_month) = billed_month), + unique (tenant, billed_month) +); +alter table billing_historicals enable row level security; +grant all on billing_historicals to postgres; + +create policy "Users must be authorized to their catalog tenant" + on billing_historicals as permissive for select + using (exists( + select 1 from auth_roles('admin') r where tenant ^@ r.role_prefix + )); +grant select on billing_historicals to authenticated; + +-- Calculate the specified month's billing report for every tenant +-- and save those reports to billing_historicals. +create function internal.freeze_billing_month(billed_month timestamptz) +returns integer as $$ +declare + tenant_row record; + tenant_count integer = 0; +begin + for tenant_row in select tenant as tenant_name from tenants loop + tenant_count = tenant_count + 1; + insert into billing_historicals + select + tenant_row.tenant_name as tenant_name, + date_trunc('month', billed_month) as billed_month, + report->'line_items' as line_items, + (coalesce(nullif(report->'processed_data_gb','null'),'0'))::numeric as processed_data_gb, + (report->'recurring_fee')::integer as recurring_fee, + (report->'subtotal')::integer as subtotal, + (coalesce(nullif(report->'task_usage_hours','null'),'0'))::numeric as task_usage_hours + from billing_report_202308(tenant_row.tenant_name, date_trunc('month', billed_month)) as report; + end loop; + return tenant_count; +end +$$ language plpgsql volatile; + +comment on table billing_historicals is + 'Historical billing statements frozen from `billing_report_202308()`.'; +comment on column billing_historicals.tenant is + 'The tenant for this statement'; +comment on column billing_historicals.billed_month is + 'The month for this statement'; +comment on column billing_historicals.line_items is + 'A list of line items composing this statement. + Line items contain `description`, `count`, `rate`, and `subtotal`.'; +comment on column billing_historicals.processed_data_gb is + 'The total number of gigabytes of data processed by this tenant this month.'; +comment on column billing_historicals.recurring_fee is + 'The fixed portion of this tenant''s bill. 0 if no recurring component.'; +comment on column billing_historicals.subtotal is + 'The subtotal in whole USD cents for this statement.'; +comment on column billing_historicals.task_usage_hours is + 'The total number of task-hours used by this tenant this month.'; + +-- The following enables the regularly scheduled function that creates +-- billing_historical for every tenant at the end of every month. +-- If you want to enable it locally, then just uncomment this +-- or run it manually. More often, it's more convenient during local +-- development to manually trigger this by calling +-- internal.freeze_billing_month() whenever you want to trigger it. + +-- create extension pg_cron with schema extensions; +-- select cron.schedule ( +-- 'month-end billing', -- name of the cron job +-- '0 0 0 2 * ? *', -- run on the second day of every month +-- $$ select internal.freeze_billing_month(now()) $$ +-- ); + +commit; + diff --git a/supabase/pending/billing_historicals.sql b/supabase/pending/billing_historicals.sql new file mode 100644 index 0000000000..c0f30959bc --- /dev/null +++ b/supabase/pending/billing_historicals.sql @@ -0,0 +1,234 @@ +create table "public"."billing_historicals" ( + "tenant" catalog_tenant not null, + "billed_month" timestamp with time zone not null, + "line_items" jsonb not null, + "processed_data_gb" numeric not null, + "recurring_fee" integer not null, + "subtotal" integer not null, + "task_usage_hours" numeric not null +); +alter table "public"."billing_historicals" enable row level security; + +CREATE UNIQUE INDEX billing_historicals_tenant_billed_month_key ON public.billing_historicals USING btree (tenant, billed_month); +alter table "public"."billing_historicals" add constraint "billing_historicals_billed_month_check" CHECK ((date_trunc('month'::text, billed_month) = billed_month)) not valid; +alter table "public"."billing_historicals" validate constraint "billing_historicals_billed_month_check"; +alter table "public"."billing_historicals" add constraint "billing_historicals_tenant_billed_month_key" UNIQUE using index "billing_historicals_tenant_billed_month_key"; + +create policy "Users must be authorized to their catalog tenant" +on "public"."billing_historicals" +as permissive +for select +to public +using ((EXISTS ( SELECT 1 + FROM auth_roles('admin'::grant_capability) r(role_prefix, capability) + WHERE ((billing_historicals.tenant)::text ^@ (r.role_prefix)::text)))); + +-- set check_function_bodies = off; + +CREATE OR REPLACE FUNCTION public.billing_report_202308(billed_prefix catalog_prefix, billed_month timestamp with time zone) + RETURNS jsonb + LANGUAGE plpgsql + SECURITY DEFINER +AS $function$ +#variable_conflict use_variable +declare + -- Auth checks + has_admin_grant boolean; + has_bypassrls boolean; + -- Retrieved from tenants table. + data_tiers integer[]; + usage_tiers integer[]; + recurring_usd_cents integer; + + -- Calculating tiered usage. + tier_rate integer; + tier_pivot integer; + tier_count numeric; + remainder numeric; + + -- Calculating adjustments. + adjustment internal.billing_adjustments; + + -- Aggregated outputs. + line_items jsonb = '[]'; + processed_data_gb numeric; + subtotal_usd_cents integer; + task_usage_hours numeric; +begin + + -- Ensure `billed_month` is the truncated start of the billed month. + billed_month = date_trunc('month', billed_month); + + -- Verify that the user has an admin grant for the requested `billed_prefix`. + perform 1 from auth_roles('admin') as r where billed_prefix ^@ r.role_prefix; + has_admin_grant = found; + + -- Check whether user has bypassrls flag + perform 1 from pg_roles where rolname = session_user and rolbypassrls = true; + has_bypassrls = found; + + if not has_bypassrls and not found then + -- errcode 28000 causes PostgREST to return an HTTP 403 + -- see: https://www.postgresql.org/docs/current/errcodes-appendix.html + -- and: https://postgrest.org/en/stable/errors.html#status-codes + raise 'You are not authorized for the billed prefix %', billed_prefix using errcode = 28000; + end if; + + -- Fetch data & usage tiers for `billed_prefix`'s tenant. + select into data_tiers, usage_tiers + t.data_tiers, t.usage_tiers + from tenants t + where billed_prefix ^@ t.tenant + ; + -- Reveal contract costs only when the computing tenant-level billing. + select into recurring_usd_cents t.recurring_usd_cents + from tenants t + where billed_prefix = t.tenant + ; + + -- Determine the total amount of data processing and task usage + -- under `billed_prefix` in the given `billed_month`. + select into processed_data_gb, task_usage_hours + sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024), + sum(usage_seconds) / (60.0 * 60) + from catalog_stats + where catalog_name ^@ billed_prefix + and grain = 'monthly' + and ts = billed_month + ; + + -- Apply a recurring service cost, if defined. + if recurring_usd_cents != 0 then + line_items = line_items || jsonb_build_object( + 'description', 'Recurring service charge', + 'count', 1, + 'rate', recurring_usd_cents, + 'subtotal', recurring_usd_cents + ); + end if; + + -- Apply each of the data processing tiers. + remainder = processed_data_gb; + + for idx in 1..array_length(data_tiers, 1) by 2 loop + tier_rate = data_tiers[idx]; + tier_pivot = data_tiers[idx+1]; + tier_count = least(remainder, tier_pivot); + remainder = remainder - tier_count; + + line_items = line_items || jsonb_build_object( + 'description', format( + case + when tier_pivot is null then 'Data processing (at %2$s/GB)' + when idx = 1 then 'Data processing (first %sGB at %s/GB)' + else 'Data processing (next %sGB at %s/GB)' + end, + tier_pivot, + (tier_rate / 100.0)::money + ), + 'count', tier_count, + 'rate', tier_rate, + 'subtotal', round(tier_count * tier_rate) + ); + end loop; + + -- Apply each of the task usage tiers. + remainder = task_usage_hours; + + for idx in 1..array_length(usage_tiers, 1) by 2 loop + tier_rate = usage_tiers[idx]; + tier_pivot = usage_tiers[idx+1]; + tier_count = least(remainder, tier_pivot); + remainder = remainder - tier_count; + + line_items = line_items || jsonb_build_object( + 'description', format( + case + when tier_pivot is null then 'Task usage (at %2$s/hour)' + when idx = 1 then 'Task usage (first %s hours at %s/hour)' + else 'Task usage (next %s hours at %s/hour)' + end, + tier_pivot, + (tier_rate / 100.0)::money + ), + 'count', tier_count, + 'rate', tier_rate, + 'subtotal', round(tier_count * tier_rate) + ); + end loop; + + -- Apply any billing adjustments. + for adjustment in select * from internal.billing_adjustments a + where a.billed_month = billed_month and a.tenant = billed_prefix + loop + line_items = line_items || jsonb_build_object( + 'description', adjustment.detail, + 'count', 1, + 'rate', adjustment.usd_cents, + 'subtotal', adjustment.usd_cents + ); + end loop; + + -- Roll up the final subtotal. + select into subtotal_usd_cents sum((l->>'subtotal')::numeric) + from jsonb_array_elements(line_items) l; + + return jsonb_build_object( + 'billed_month', billed_month, + 'billed_prefix', billed_prefix, + 'line_items', line_items, + 'processed_data_gb', processed_data_gb, + 'recurring_fee', coalesce(recurring_usd_cents, 0), + 'subtotal', subtotal_usd_cents, + 'task_usage_hours', task_usage_hours + ); + +end +$function$ +; + +CREATE OR REPLACE FUNCTION internal.freeze_billing_month(billed_month timestamp with time zone) + RETURNS integer + LANGUAGE plpgsql +AS $function$ +declare + tenant_row record; + tenant_count integer = 0; +begin + for tenant_row in select tenant as tenant_name from tenants loop + tenant_count = tenant_count + 1; + insert into billing_historicals + select + tenant_row.tenant_name as tenant_name, + date_trunc('month', billed_month) as billed_month, + report->'line_items' as line_items, + (coalesce(nullif(report->'processed_data_gb','null'),'0'))::numeric as processed_data_gb, + (report->'recurring_fee')::integer as recurring_fee, + (report->'subtotal')::integer as subtotal, + (coalesce(nullif(report->'task_usage_hours','null'),'0'))::numeric as task_usage_hours + from billing_report_202308(tenant_row.tenant_name, date_trunc('month', billed_month)) as report; + end loop; + return tenant_count; +end +$function$ +; + +-- Had to manually add these +comment on table billing_historicals is + 'Historical billing statements frozen from `billing_report_202308()`.'; +comment on column billing_historicals.tenant is + 'The tenant for this statement'; +comment on column billing_historicals.billed_month is + 'The month for this statement'; +comment on column billing_historicals.line_items is + 'A list of line items composing this statement. + Line items contain `description`, `count`, `rate`, and `subtotal`.'; +comment on column billing_historicals.processed_data_gb is + 'The total number of gigabytes of data processed by this tenant this month.'; +comment on column billing_historicals.recurring_fee is + 'The fixed portion of this tenant''s bill. 0 if no recurring component.'; +comment on column billing_historicals.subtotal is + 'The subtotal in whole USD cents for this statement.'; +comment on column billing_historicals.task_usage_hours is + 'The total number of task-hours used by this tenant this month.'; + From 40a35c073a272f2dcdb69f154a8ce3e558de2ed9 Mon Sep 17 00:00:00 2001 From: Joseph Shearer Date: Mon, 28 Aug 2023 15:09:36 -0400 Subject: [PATCH 2/8] Capture entire billing report as JSON, instead of extracting specific fields --- supabase/migrations/21_billing_v2.sql | 11 +- .../migrations/24_billing_historicals.sql | 185 ++++++++++++++++-- 2 files changed, 165 insertions(+), 31 deletions(-) diff --git a/supabase/migrations/21_billing_v2.sql b/supabase/migrations/21_billing_v2.sql index 74cc47e4ce..d163c95bb0 100644 --- a/supabase/migrations/21_billing_v2.sql +++ b/supabase/migrations/21_billing_v2.sql @@ -148,9 +148,6 @@ create function billing_report_202308(billed_prefix catalog_prefix, billed_month returns jsonb as $$ #variable_conflict use_variable declare - -- Auth checks - has_admin_grant boolean; - has_bypassrls boolean; -- Retrieved from tenants table. data_tiers integer[]; usage_tiers integer[]; @@ -177,13 +174,7 @@ begin -- Verify that the user has an admin grant for the requested `billed_prefix`. perform 1 from auth_roles('admin') as r where billed_prefix ^@ r.role_prefix; - has_admin_grant = found; - - -- Check whether user has bypassrls flag - perform 1 from pg_roles where rolname = session_user and rolbypassrls = true; - has_bypassrls = found; - - if not has_bypassrls and not found then + if not found then -- errcode 28000 causes PostgREST to return an HTTP 403 -- see: https://www.postgresql.org/docs/current/errcodes-appendix.html -- and: https://postgrest.org/en/stable/errors.html#status-codes diff --git a/supabase/migrations/24_billing_historicals.sql b/supabase/migrations/24_billing_historicals.sql index da1647f01e..a91fe6a370 100644 --- a/supabase/migrations/24_billing_historicals.sql +++ b/supabase/migrations/24_billing_historicals.sql @@ -7,11 +7,7 @@ begin; create table billing_historicals ( tenant catalog_tenant not null, billed_month timestamptz not null, - line_items jsonb not null, - processed_data_gb numeric not null, - recurring_fee integer not null, - subtotal integer not null, - task_usage_hours numeric not null + report jsonb not null, check (date_trunc('month', billed_month) = billed_month), unique (tenant, billed_month) @@ -40,11 +36,7 @@ begin select tenant_row.tenant_name as tenant_name, date_trunc('month', billed_month) as billed_month, - report->'line_items' as line_items, - (coalesce(nullif(report->'processed_data_gb','null'),'0'))::numeric as processed_data_gb, - (report->'recurring_fee')::integer as recurring_fee, - (report->'subtotal')::integer as subtotal, - (coalesce(nullif(report->'task_usage_hours','null'),'0'))::numeric as task_usage_hours + report from billing_report_202308(tenant_row.tenant_name, date_trunc('month', billed_month)) as report; end loop; return tenant_count; @@ -57,17 +49,168 @@ comment on column billing_historicals.tenant is 'The tenant for this statement'; comment on column billing_historicals.billed_month is 'The month for this statement'; -comment on column billing_historicals.line_items is - 'A list of line items composing this statement. - Line items contain `description`, `count`, `rate`, and `subtotal`.'; -comment on column billing_historicals.processed_data_gb is - 'The total number of gigabytes of data processed by this tenant this month.'; -comment on column billing_historicals.recurring_fee is - 'The fixed portion of this tenant''s bill. 0 if no recurring component.'; -comment on column billing_historicals.subtotal is - 'The subtotal in whole USD cents for this statement.'; -comment on column billing_historicals.task_usage_hours is - 'The total number of task-hours used by this tenant this month.'; +comment on column billing_historicals.report is + 'The report generated by billing_report_202308()'; + + +-- Billing report which is effective August 2023. +create or replace function billing_report_202308(billed_prefix catalog_prefix, billed_month timestamptz) +returns jsonb as $$ +#variable_conflict use_variable +declare + -- Auth checks + has_admin_grant boolean; + has_bypassrls boolean; + -- Retrieved from tenants table. + data_tiers integer[]; + usage_tiers integer[]; + recurring_usd_cents integer; + + -- Calculating tiered usage. + tier_rate integer; + tier_pivot integer; + tier_count numeric; + remainder numeric; + + -- Calculating adjustments. + adjustment internal.billing_adjustments; + + -- Aggregated outputs. + line_items jsonb = '[]'; + processed_data_gb numeric; + subtotal_usd_cents integer; + task_usage_hours numeric; +begin + + -- Ensure `billed_month` is the truncated start of the billed month. + billed_month = date_trunc('month', billed_month); + + -- Verify that the user has an admin grant for the requested `billed_prefix`. + perform 1 from auth_roles('admin') as r where billed_prefix ^@ r.role_prefix; + has_admin_grant = found; + + -- Check whether user has bypassrls flag + perform 1 from pg_roles where rolname = session_user and rolbypassrls = true; + has_bypassrls = found; + + if not has_bypassrls and not has_admin_grant then + -- errcode 28000 causes PostgREST to return an HTTP 403 + -- see: https://www.postgresql.org/docs/current/errcodes-appendix.html + -- and: https://postgrest.org/en/stable/errors.html#status-codes + raise 'You are not authorized for the billed prefix %', billed_prefix using errcode = 28000; + end if; + + -- Fetch data & usage tiers for `billed_prefix`'s tenant. + select into data_tiers, usage_tiers + t.data_tiers, t.usage_tiers + from tenants t + where billed_prefix ^@ t.tenant + ; + -- Reveal contract costs only when the computing tenant-level billing. + select into recurring_usd_cents t.recurring_usd_cents + from tenants t + where billed_prefix = t.tenant + ; + + -- Determine the total amount of data processing and task usage + -- under `billed_prefix` in the given `billed_month`. + select into processed_data_gb, task_usage_hours + sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024), + sum(usage_seconds) / (60.0 * 60) + from catalog_stats + where catalog_name ^@ billed_prefix + and grain = 'monthly' + and ts = billed_month + ; + + -- Apply a recurring service cost, if defined. + if recurring_usd_cents != 0 then + line_items = line_items || jsonb_build_object( + 'description', 'Recurring service charge', + 'count', 1, + 'rate', recurring_usd_cents, + 'subtotal', recurring_usd_cents + ); + end if; + + -- Apply each of the data processing tiers. + remainder = processed_data_gb; + + for idx in 1..array_length(data_tiers, 1) by 2 loop + tier_rate = data_tiers[idx]; + tier_pivot = data_tiers[idx+1]; + tier_count = least(remainder, tier_pivot); + remainder = remainder - tier_count; + + line_items = line_items || jsonb_build_object( + 'description', format( + case + when tier_pivot is null then 'Data processing (at %2$s/GB)' + when idx = 1 then 'Data processing (first %sGB at %s/GB)' + else 'Data processing (next %sGB at %s/GB)' + end, + tier_pivot, + (tier_rate / 100.0)::money + ), + 'count', tier_count, + 'rate', tier_rate, + 'subtotal', round(tier_count * tier_rate) + ); + end loop; + + -- Apply each of the task usage tiers. + remainder = task_usage_hours; + + for idx in 1..array_length(usage_tiers, 1) by 2 loop + tier_rate = usage_tiers[idx]; + tier_pivot = usage_tiers[idx+1]; + tier_count = least(remainder, tier_pivot); + remainder = remainder - tier_count; + + line_items = line_items || jsonb_build_object( + 'description', format( + case + when tier_pivot is null then 'Task usage (at %2$s/hour)' + when idx = 1 then 'Task usage (first %s hours at %s/hour)' + else 'Task usage (next %s hours at %s/hour)' + end, + tier_pivot, + (tier_rate / 100.0)::money + ), + 'count', tier_count, + 'rate', tier_rate, + 'subtotal', round(tier_count * tier_rate) + ); + end loop; + + -- Apply any billing adjustments. + for adjustment in select * from internal.billing_adjustments a + where a.billed_month = billed_month and a.tenant = billed_prefix + loop + line_items = line_items || jsonb_build_object( + 'description', adjustment.detail, + 'count', 1, + 'rate', adjustment.usd_cents, + 'subtotal', adjustment.usd_cents + ); + end loop; + + -- Roll up the final subtotal. + select into subtotal_usd_cents sum((l->>'subtotal')::numeric) + from jsonb_array_elements(line_items) l; + + return jsonb_build_object( + 'billed_month', billed_month, + 'billed_prefix', billed_prefix, + 'line_items', line_items, + 'processed_data_gb', processed_data_gb, + 'recurring_fee', coalesce(recurring_usd_cents, 0), + 'subtotal', subtotal_usd_cents, + 'task_usage_hours', task_usage_hours + ); + +end +$$ language plpgsql volatile security definer; -- The following enables the regularly scheduled function that creates -- billing_historical for every tenant at the end of every month. From 1e6e43045d7a9c9ebafc9b0828b3b039d762b22c Mon Sep 17 00:00:00 2001 From: Joseph Shearer Date: Mon, 28 Aug 2023 15:09:52 -0400 Subject: [PATCH 3/8] Remove pending migration --- supabase/pending/billing_historicals.sql | 234 ----------------------- 1 file changed, 234 deletions(-) delete mode 100644 supabase/pending/billing_historicals.sql diff --git a/supabase/pending/billing_historicals.sql b/supabase/pending/billing_historicals.sql deleted file mode 100644 index c0f30959bc..0000000000 --- a/supabase/pending/billing_historicals.sql +++ /dev/null @@ -1,234 +0,0 @@ -create table "public"."billing_historicals" ( - "tenant" catalog_tenant not null, - "billed_month" timestamp with time zone not null, - "line_items" jsonb not null, - "processed_data_gb" numeric not null, - "recurring_fee" integer not null, - "subtotal" integer not null, - "task_usage_hours" numeric not null -); -alter table "public"."billing_historicals" enable row level security; - -CREATE UNIQUE INDEX billing_historicals_tenant_billed_month_key ON public.billing_historicals USING btree (tenant, billed_month); -alter table "public"."billing_historicals" add constraint "billing_historicals_billed_month_check" CHECK ((date_trunc('month'::text, billed_month) = billed_month)) not valid; -alter table "public"."billing_historicals" validate constraint "billing_historicals_billed_month_check"; -alter table "public"."billing_historicals" add constraint "billing_historicals_tenant_billed_month_key" UNIQUE using index "billing_historicals_tenant_billed_month_key"; - -create policy "Users must be authorized to their catalog tenant" -on "public"."billing_historicals" -as permissive -for select -to public -using ((EXISTS ( SELECT 1 - FROM auth_roles('admin'::grant_capability) r(role_prefix, capability) - WHERE ((billing_historicals.tenant)::text ^@ (r.role_prefix)::text)))); - --- set check_function_bodies = off; - -CREATE OR REPLACE FUNCTION public.billing_report_202308(billed_prefix catalog_prefix, billed_month timestamp with time zone) - RETURNS jsonb - LANGUAGE plpgsql - SECURITY DEFINER -AS $function$ -#variable_conflict use_variable -declare - -- Auth checks - has_admin_grant boolean; - has_bypassrls boolean; - -- Retrieved from tenants table. - data_tiers integer[]; - usage_tiers integer[]; - recurring_usd_cents integer; - - -- Calculating tiered usage. - tier_rate integer; - tier_pivot integer; - tier_count numeric; - remainder numeric; - - -- Calculating adjustments. - adjustment internal.billing_adjustments; - - -- Aggregated outputs. - line_items jsonb = '[]'; - processed_data_gb numeric; - subtotal_usd_cents integer; - task_usage_hours numeric; -begin - - -- Ensure `billed_month` is the truncated start of the billed month. - billed_month = date_trunc('month', billed_month); - - -- Verify that the user has an admin grant for the requested `billed_prefix`. - perform 1 from auth_roles('admin') as r where billed_prefix ^@ r.role_prefix; - has_admin_grant = found; - - -- Check whether user has bypassrls flag - perform 1 from pg_roles where rolname = session_user and rolbypassrls = true; - has_bypassrls = found; - - if not has_bypassrls and not found then - -- errcode 28000 causes PostgREST to return an HTTP 403 - -- see: https://www.postgresql.org/docs/current/errcodes-appendix.html - -- and: https://postgrest.org/en/stable/errors.html#status-codes - raise 'You are not authorized for the billed prefix %', billed_prefix using errcode = 28000; - end if; - - -- Fetch data & usage tiers for `billed_prefix`'s tenant. - select into data_tiers, usage_tiers - t.data_tiers, t.usage_tiers - from tenants t - where billed_prefix ^@ t.tenant - ; - -- Reveal contract costs only when the computing tenant-level billing. - select into recurring_usd_cents t.recurring_usd_cents - from tenants t - where billed_prefix = t.tenant - ; - - -- Determine the total amount of data processing and task usage - -- under `billed_prefix` in the given `billed_month`. - select into processed_data_gb, task_usage_hours - sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024), - sum(usage_seconds) / (60.0 * 60) - from catalog_stats - where catalog_name ^@ billed_prefix - and grain = 'monthly' - and ts = billed_month - ; - - -- Apply a recurring service cost, if defined. - if recurring_usd_cents != 0 then - line_items = line_items || jsonb_build_object( - 'description', 'Recurring service charge', - 'count', 1, - 'rate', recurring_usd_cents, - 'subtotal', recurring_usd_cents - ); - end if; - - -- Apply each of the data processing tiers. - remainder = processed_data_gb; - - for idx in 1..array_length(data_tiers, 1) by 2 loop - tier_rate = data_tiers[idx]; - tier_pivot = data_tiers[idx+1]; - tier_count = least(remainder, tier_pivot); - remainder = remainder - tier_count; - - line_items = line_items || jsonb_build_object( - 'description', format( - case - when tier_pivot is null then 'Data processing (at %2$s/GB)' - when idx = 1 then 'Data processing (first %sGB at %s/GB)' - else 'Data processing (next %sGB at %s/GB)' - end, - tier_pivot, - (tier_rate / 100.0)::money - ), - 'count', tier_count, - 'rate', tier_rate, - 'subtotal', round(tier_count * tier_rate) - ); - end loop; - - -- Apply each of the task usage tiers. - remainder = task_usage_hours; - - for idx in 1..array_length(usage_tiers, 1) by 2 loop - tier_rate = usage_tiers[idx]; - tier_pivot = usage_tiers[idx+1]; - tier_count = least(remainder, tier_pivot); - remainder = remainder - tier_count; - - line_items = line_items || jsonb_build_object( - 'description', format( - case - when tier_pivot is null then 'Task usage (at %2$s/hour)' - when idx = 1 then 'Task usage (first %s hours at %s/hour)' - else 'Task usage (next %s hours at %s/hour)' - end, - tier_pivot, - (tier_rate / 100.0)::money - ), - 'count', tier_count, - 'rate', tier_rate, - 'subtotal', round(tier_count * tier_rate) - ); - end loop; - - -- Apply any billing adjustments. - for adjustment in select * from internal.billing_adjustments a - where a.billed_month = billed_month and a.tenant = billed_prefix - loop - line_items = line_items || jsonb_build_object( - 'description', adjustment.detail, - 'count', 1, - 'rate', adjustment.usd_cents, - 'subtotal', adjustment.usd_cents - ); - end loop; - - -- Roll up the final subtotal. - select into subtotal_usd_cents sum((l->>'subtotal')::numeric) - from jsonb_array_elements(line_items) l; - - return jsonb_build_object( - 'billed_month', billed_month, - 'billed_prefix', billed_prefix, - 'line_items', line_items, - 'processed_data_gb', processed_data_gb, - 'recurring_fee', coalesce(recurring_usd_cents, 0), - 'subtotal', subtotal_usd_cents, - 'task_usage_hours', task_usage_hours - ); - -end -$function$ -; - -CREATE OR REPLACE FUNCTION internal.freeze_billing_month(billed_month timestamp with time zone) - RETURNS integer - LANGUAGE plpgsql -AS $function$ -declare - tenant_row record; - tenant_count integer = 0; -begin - for tenant_row in select tenant as tenant_name from tenants loop - tenant_count = tenant_count + 1; - insert into billing_historicals - select - tenant_row.tenant_name as tenant_name, - date_trunc('month', billed_month) as billed_month, - report->'line_items' as line_items, - (coalesce(nullif(report->'processed_data_gb','null'),'0'))::numeric as processed_data_gb, - (report->'recurring_fee')::integer as recurring_fee, - (report->'subtotal')::integer as subtotal, - (coalesce(nullif(report->'task_usage_hours','null'),'0'))::numeric as task_usage_hours - from billing_report_202308(tenant_row.tenant_name, date_trunc('month', billed_month)) as report; - end loop; - return tenant_count; -end -$function$ -; - --- Had to manually add these -comment on table billing_historicals is - 'Historical billing statements frozen from `billing_report_202308()`.'; -comment on column billing_historicals.tenant is - 'The tenant for this statement'; -comment on column billing_historicals.billed_month is - 'The month for this statement'; -comment on column billing_historicals.line_items is - 'A list of line items composing this statement. - Line items contain `description`, `count`, `rate`, and `subtotal`.'; -comment on column billing_historicals.processed_data_gb is - 'The total number of gigabytes of data processed by this tenant this month.'; -comment on column billing_historicals.recurring_fee is - 'The fixed portion of this tenant''s bill. 0 if no recurring component.'; -comment on column billing_historicals.subtotal is - 'The subtotal in whole USD cents for this statement.'; -comment on column billing_historicals.task_usage_hours is - 'The total number of task-hours used by this tenant this month.'; - From 7519fc87b9ea813ec676da3116d63a891ea3b73c Mon Sep 17 00:00:00 2001 From: Joseph Shearer Date: Mon, 28 Aug 2023 15:24:46 -0400 Subject: [PATCH 4/8] Change `tenant` to `billed_prefix` to be consistent with existing billing report --- supabase/migrations/24_billing_historicals.sql | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/supabase/migrations/24_billing_historicals.sql b/supabase/migrations/24_billing_historicals.sql index a91fe6a370..b2db190704 100644 --- a/supabase/migrations/24_billing_historicals.sql +++ b/supabase/migrations/24_billing_historicals.sql @@ -5,12 +5,12 @@ begin; -- Historical record of tenant billing statements. This structure -- comes from the return value of `billing_report_202308`. create table billing_historicals ( - tenant catalog_tenant not null, + billed_prefix catalog_tenant not null, billed_month timestamptz not null, report jsonb not null, check (date_trunc('month', billed_month) = billed_month), - unique (tenant, billed_month) + unique (billed_prefix, billed_month) ); alter table billing_historicals enable row level security; grant all on billing_historicals to postgres; @@ -18,7 +18,7 @@ grant all on billing_historicals to postgres; create policy "Users must be authorized to their catalog tenant" on billing_historicals as permissive for select using (exists( - select 1 from auth_roles('admin') r where tenant ^@ r.role_prefix + select 1 from auth_roles('admin') r where billed_prefix ^@ r.role_prefix )); grant select on billing_historicals to authenticated; @@ -34,7 +34,7 @@ begin tenant_count = tenant_count + 1; insert into billing_historicals select - tenant_row.tenant_name as tenant_name, + tenant_row.tenant_name as billed_prefix, date_trunc('month', billed_month) as billed_month, report from billing_report_202308(tenant_row.tenant_name, date_trunc('month', billed_month)) as report; @@ -45,7 +45,7 @@ $$ language plpgsql volatile; comment on table billing_historicals is 'Historical billing statements frozen from `billing_report_202308()`.'; -comment on column billing_historicals.tenant is +comment on column billing_historicals.billed_prefix is 'The tenant for this statement'; comment on column billing_historicals.billed_month is 'The month for this statement'; From 0fd0b74b07fe66169d357286c6c384d79367d2f7 Mon Sep 17 00:00:00 2001 From: Joseph Shearer Date: Mon, 28 Aug 2023 17:04:28 -0400 Subject: [PATCH 5/8] fix: correct cron comment --- supabase/migrations/24_billing_historicals.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/supabase/migrations/24_billing_historicals.sql b/supabase/migrations/24_billing_historicals.sql index b2db190704..61296f793e 100644 --- a/supabase/migrations/24_billing_historicals.sql +++ b/supabase/migrations/24_billing_historicals.sql @@ -223,7 +223,7 @@ $$ language plpgsql volatile security definer; -- select cron.schedule ( -- 'month-end billing', -- name of the cron job -- '0 0 0 2 * ? *', -- run on the second day of every month --- $$ select internal.freeze_billing_month(now()) $$ +-- $$ select internal.freeze_billing_month(date_trunc('month', current_date - interval '1 month')) $$ -- ); commit; From 91b5a95e12102cd67eeed4b10e323e31f3977fc4 Mon Sep 17 00:00:00 2001 From: Joseph Shearer Date: Tue, 29 Aug 2023 13:41:09 -0400 Subject: [PATCH 6/8] Address PR feedback --- supabase/migrations/24_billing_historicals.sql | 17 ++++++++--------- 1 file changed, 8 insertions(+), 9 deletions(-) diff --git a/supabase/migrations/24_billing_historicals.sql b/supabase/migrations/24_billing_historicals.sql index 61296f793e..4edb326736 100644 --- a/supabase/migrations/24_billing_historicals.sql +++ b/supabase/migrations/24_billing_historicals.sql @@ -5,20 +5,19 @@ begin; -- Historical record of tenant billing statements. This structure -- comes from the return value of `billing_report_202308`. create table billing_historicals ( - billed_prefix catalog_tenant not null, + tenant catalog_tenant not null, billed_month timestamptz not null, report jsonb not null, check (date_trunc('month', billed_month) = billed_month), - unique (billed_prefix, billed_month) + unique (tenant, billed_month) ); alter table billing_historicals enable row level security; -grant all on billing_historicals to postgres; create policy "Users must be authorized to their catalog tenant" on billing_historicals as permissive for select using (exists( - select 1 from auth_roles('admin') r where billed_prefix ^@ r.role_prefix + select 1 from auth_roles('admin') r where tenant ^@ r.role_prefix )); grant select on billing_historicals to authenticated; @@ -34,7 +33,7 @@ begin tenant_count = tenant_count + 1; insert into billing_historicals select - tenant_row.tenant_name as billed_prefix, + report->>'billed_prefix' as tenant, date_trunc('month', billed_month) as billed_month, report from billing_report_202308(tenant_row.tenant_name, date_trunc('month', billed_month)) as report; @@ -45,12 +44,12 @@ $$ language plpgsql volatile; comment on table billing_historicals is 'Historical billing statements frozen from `billing_report_202308()`.'; -comment on column billing_historicals.billed_prefix is - 'The tenant for this statement'; +comment on column billing_historicals.tenant is + 'The tenant for this billing statement'; comment on column billing_historicals.billed_month is - 'The month for this statement'; + 'The month for this billing statement'; comment on column billing_historicals.report is - 'The report generated by billing_report_202308()'; + 'The historical billing report generated by billing_report_202308()'; -- Billing report which is effective August 2023. From 046c78785e3e7efb564e0a8dff427674508d5513 Mon Sep 17 00:00:00 2001 From: Joseph Shearer Date: Tue, 29 Aug 2023 13:52:45 -0400 Subject: [PATCH 7/8] Don't error if there are existing billing historical rows for that tenant/month --- supabase/migrations/24_billing_historicals.sql | 11 ++++++++--- 1 file changed, 8 insertions(+), 3 deletions(-) diff --git a/supabase/migrations/24_billing_historicals.sql b/supabase/migrations/24_billing_historicals.sql index 4edb326736..1ea38d586c 100644 --- a/supabase/migrations/24_billing_historicals.sql +++ b/supabase/migrations/24_billing_historicals.sql @@ -30,13 +30,18 @@ declare tenant_count integer = 0; begin for tenant_row in select tenant as tenant_name from tenants loop - tenant_count = tenant_count + 1; insert into billing_historicals select report->>'billed_prefix' as tenant, - date_trunc('month', billed_month) as billed_month, + (report->>'billed_month')::timestamptz as billed_month, report - from billing_report_202308(tenant_row.tenant_name, date_trunc('month', billed_month)) as report; + from billing_report_202308(tenant_row.tenant_name, billed_month) as report + on conflict do nothing; + + -- INSERT statements set FOUND true if at least one row is affected, false if no row is affected. + if found then + tenant_count = tenant_count + 1; + end if; end loop; return tenant_count; end From c1017e75c87eae616fd9296c8c50ef47d94b3bcd Mon Sep 17 00:00:00 2001 From: Joseph Shearer Date: Tue, 29 Aug 2023 14:25:45 -0400 Subject: [PATCH 8/8] fix: properly handle tenants with no stats at all --- supabase/migrations/24_billing_historicals.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/supabase/migrations/24_billing_historicals.sql b/supabase/migrations/24_billing_historicals.sql index 1ea38d586c..8582f47820 100644 --- a/supabase/migrations/24_billing_historicals.sql +++ b/supabase/migrations/24_billing_historicals.sql @@ -119,8 +119,8 @@ begin -- Determine the total amount of data processing and task usage -- under `billed_prefix` in the given `billed_month`. select into processed_data_gb, task_usage_hours - sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024), - sum(usage_seconds) / (60.0 * 60) + coalesce(sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024),0), + coalesce(sum(usage_seconds) / (60.0 * 60), 0) from catalog_stats where catalog_name ^@ billed_prefix and grain = 'monthly'