Skip to content

Commit

Permalink
feature: Implement billing_historicals table (#1163)
Browse files Browse the repository at this point in the history
* 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.

* fix: properly handle tenants with no stats at all
  • Loading branch information
jshearer authored Aug 29, 2023
1 parent 1c9ed48 commit 70beb4d
Showing 1 changed file with 234 additions and 0 deletions.
234 changes: 234 additions & 0 deletions supabase/migrations/24_billing_historicals.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,234 @@

-- 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,
report jsonb not null,

check (date_trunc('month', billed_month) = billed_month),
unique (tenant, billed_month)
);
alter table billing_historicals enable row level security;

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
insert into billing_historicals
select
report->>'billed_prefix' as tenant,
(report->>'billed_month')::timestamptz as billed_month,
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
$$ 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 billing statement';
comment on column billing_historicals.billed_month is
'The month for this billing statement';
comment on column billing_historicals.report is
'The historical billing 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
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'
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.
-- 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(date_trunc('month', current_date - interval '1 month')) $$
-- );

commit;

0 comments on commit 70beb4d

Please sign in to comment.