diff --git a/crates/agent-sql/tests/connector_tags.rs b/crates/agent-sql/tests/connector_tags.rs index 6b80926374..3c42cb2fa5 100644 --- a/crates/agent-sql/tests/connector_tags.rs +++ b/crates/agent-sql/tests/connector_tags.rs @@ -15,8 +15,8 @@ async fn resource_path_pointers_cannot_be_changed() { let row = sqlx::query!( r#" with setup_connectors as ( - insert into connectors (image_name, external_url, title, short_description, logo_url) - values ('foo/image', 'http://test.test', '{"en-US": "foo"}', '{"en-US": "foo"}', '{"en-US": "foo"}') + insert into connectors (image_name, external_url, title, short_description, logo_url, recommended) + values ('foo/image', 'http://test.test', '{"en-US": "foo"}', '{"en-US": "foo"}', '{"en-US": "foo"}', false) returning id ) insert into connector_tags (connector_id, image_tag) select id, ':test' as image_tag from setup_connectors diff --git a/crates/agent-sql/tests/publications.rs b/crates/agent-sql/tests/publications.rs index c12e5decc1..efc0b43540 100644 --- a/crates/agent-sql/tests/publications.rs +++ b/crates/agent-sql/tests/publications.rs @@ -20,8 +20,8 @@ async fn test_finding_forbidden_connectors() { ('bb00000000000000', 'testConnectors/Allowed', '{}'::json, 'capture', 'allowed_image', 'bbbbbbbbbbbbbbbb', 'bbbbbbbbbbbbbbbb') ), p2 as ( - insert into connectors (external_url, image_name, title, short_description, logo_url) values - ('http://example.com', 'allowed_image', '{"en-US": "foo"}'::json, '{"en-US": "foo"}'::json, '{"en-US": "foo"}'::json) + insert into connectors (external_url, image_name, title, short_description, logo_url, recommended) values + ('http://example.com', 'allowed_image', '{"en-US": "foo"}'::json, '{"en-US": "foo"}'::json, '{"en-US": "foo"}'::json, false) ) select 1; "#, diff --git a/crates/agent/src/integration_tests/harness.rs b/crates/agent/src/integration_tests/harness.rs index 96c486a4cb..0bf3488999 100644 --- a/crates/agent/src/integration_tests/harness.rs +++ b/crates/agent/src/integration_tests/harness.rs @@ -126,14 +126,14 @@ impl TestHarness { async fn setup_test_connectors(&mut self) { sqlx::query!(r##" with source_image as ( - insert into connectors (external_url, image_name, title, short_description, logo_url) - values ('http://test.test/', 'source/test', '{"en-US": "test"}', '{"en-US": "test"}', '{"en-US": "http://test.test/"}') + insert into connectors (external_url, image_name, title, short_description, logo_url, recommended) + values ('http://test.test/', 'source/test', '{"en-US": "test"}', '{"en-US": "test"}', '{"en-US": "http://test.test/"}', false) on conflict(image_name) do update set title = excluded.title returning id ), materialize_image as ( - insert into connectors (external_url, image_name, title, short_description, logo_url) - values ('http://test.test/', 'materialize/test', '{"en-US": "test"}', '{"en-US": "test"}', '{"en-US": "http://test.test/"}') + insert into connectors (external_url, image_name, title, short_description, logo_url, recommended) + values ('http://test.test/', 'materialize/test', '{"en-US": "test"}', '{"en-US": "test"}', '{"en-US": "http://test.test/"}', false) on conflict(image_name) do update set title = excluded.title returning id ), diff --git a/crates/agent/src/integration_tests/source_captures.rs b/crates/agent/src/integration_tests/source_captures.rs index 1d5dd9e8bd..287b0b5015 100644 --- a/crates/agent/src/integration_tests/source_captures.rs +++ b/crates/agent/src/integration_tests/source_captures.rs @@ -283,7 +283,7 @@ async fn test_source_captures_collection_name() { #[tokio::test] #[serial_test::serial] async fn test_source_capture_no_annotations() { - let mut harness = TestHarness::init("test_source_capture_no_annotations").await; + let harness = TestHarness::init("test_source_capture_no_annotations").await; let user_id = harness.setup_tenant("sheep").await; let draft = draft_catalog(serde_json::json!({ diff --git a/crates/agent/src/integration_tests/unknown_connectors.rs b/crates/agent/src/integration_tests/unknown_connectors.rs index bba713aea1..afe4d07226 100644 --- a/crates/agent/src/integration_tests/unknown_connectors.rs +++ b/crates/agent/src/integration_tests/unknown_connectors.rs @@ -6,7 +6,7 @@ use crate::integration_tests::harness::{draft_catalog, TestHarness}; #[tokio::test] #[serial_test::serial] async fn test_forbidden_connector() { - let mut harness = TestHarness::init("test_forbidden_connector").await; + let harness = TestHarness::init("test_forbidden_connector").await; let user_id = harness.setup_tenant("sheep").await; let draft = draft_catalog(serde_json::json!({ diff --git a/supabase/migrations/00_polyfill.sql b/supabase/migrations/00_polyfill.sql new file mode 100644 index 0000000000..2fe9327534 --- /dev/null +++ b/supabase/migrations/00_polyfill.sql @@ -0,0 +1,54 @@ +begin; + +-- Roles which are created by supabase: anon, authenticated, supabase_admin, service_role. + +create role stats_loader with login password 'stats_loader_password' bypassrls; +create role marketplace_integration; +create role gatsby_reader; +create role github_action_connector_refresh; +create role wgd_automation; +create role reporting_user; + +-- Required for postgres to give ownership of catalog_stats to stats_loader. +grant stats_loader to postgres; + +-- Required for stats materialization to create flow_checkpoints_v1 and flow_materializations_v2. +grant create on schema public to stats_loader; + +-- TODO(johnny): Required for `authenticated` to own `drafts_ext` and `publication_specs_ext`. +-- We should make them owed by postgres and grant usage instead. +grant create on schema public to authenticated; + +-- The production database has a Flow materialization of Stripe customer data. +-- This is a partial table which matches the portions we use today. +create schema stripe; + +create table stripe.customers ( + id text primary key, + address json, + "address/city" text, + "address/country" text, + "address/line1" text, + "address/line2" text, + "address/postal_code" text, + "address/state" text, + balance bigint, + created bigint, + currency text, + default_source text, + delinquent boolean, + description text, + email text, + invoice_prefix text, + invoice_settings json, + "invoice_settings/custom_fields" json, + "invoice_settings/default_payment_method" text, + metadata json, + name text, + phone text, + flow_document json not null +); + +grant usage on schema stripe to postgres; + +commit; \ No newline at end of file diff --git a/supabase/migrations/01_json.sql b/supabase/migrations/01_json.sql deleted file mode 100644 index 4bb34624cc..0000000000 --- a/supabase/migrations/01_json.sql +++ /dev/null @@ -1,96 +0,0 @@ --- We write SQL according to https://www.sqlstyle.guide/ --- It's an arbitrary style guide, but it's important to have one for consistency. --- We also lower-case SQL keywords, as is common within Supabase documentation. - -create domain json_obj as json check (json_typeof(value) = 'object'); -comment on domain json_obj is - 'json_obj is JSON which is restricted to the "object" type'; - -create domain jsonb_obj as jsonb check (jsonb_typeof(value) = 'object'); -comment on domain jsonb_obj is - 'jsonb_obj is JSONB which is restricted to the "object" type'; - -create schema internal; -comment on schema internal is - 'Internal schema used for types, tables, and procedures we don''t expose in our API'; - --- jsonb_merge_patch "target" with "patch" as a RFC 7396 JSON Merge Patch. -create function internal.jsonb_merge_patch("target" jsonb, "patch" jsonb) -returns jsonb as $$ -begin - case - when "patch" is null then - return "target"; - when "patch" = 'null' then - return null; -- Remove location. - when jsonb_typeof("target") is distinct from 'object' or - jsonb_typeof("patch") is distinct from 'object' then - -- If either side is not an object, take the patch. - return jsonb_strip_nulls("patch"); - when "target" = jsonb_strip_nulls("patch") then - -- Both are objects, and the patch doesn't change the target. - -- This case *could* be handled by the recursive case, - -- but equality and stripping nulls is dirt cheap compared to - -- the cost of recursive jsonb_object_agg, which must repeatedly - -- copy nested sub-structure. - return "target"; - else - return ( - with props as ( - select - coalesce("tkey", "pkey") as "key", - case - when "pval" isnull then "tval" - else internal.jsonb_merge_patch("tval", "pval") - end as "val" - from jsonb_each("target") e1("tkey", "tval") - full outer join jsonb_each("patch") e2("pkey", "pval") on "tkey" = "pkey" - where "pval" is distinct from 'null' - ) - select coalesce(jsonb_object_agg("key", "val"), '{}') from props - ); - end case; -end; -$$ language plpgsql immutable; - - --- jsonb_merge_diff "target" with "source" to derive a RFC 7396 JSON Merge Patch --- which will patch source into target. JSON 'null' locations in both source and --- target are permitted, but it's not possible to patch a source location into a --- 'null' value, as this isn't a supported operation by JSON merge patch. --- In this case, this function will instead explicitly remove the location. --- --- Be careful when returning a jsonb_merge_diff result as JSON, because a --- returned NULL means "there is no difference", while JSON 'null' means --- "remove the entire document". JSON serialization will collapse both cases --- to JSON 'null'. To fix this, first coalesce the result of this function into --- the expected top-level type, such as "coalesce(my_patch, '{}')". -create function internal.jsonb_merge_diff("target" jsonb, "source" jsonb) -returns jsonb as $$ -begin - case - when "target" isnull then - return 'null'; -- Marker to remove location. - when jsonb_typeof("target") is distinct from 'object' or - jsonb_typeof("source") is distinct from 'object' then - return (case - when "target" = "source" then null - else jsonb_strip_nulls("target") - end); - else - return ( - with props as ( - select - coalesce("tkey", "skey") as "key", - internal.jsonb_merge_diff("tval", "sval") as "val" - from jsonb_each("target") e1("tkey", "tval") - full outer join jsonb_each("source") e2("skey", "sval") on "tkey" = "skey" - ) - -- If no props are different, the result is NULL (not 'null'). - select jsonb_object_agg("key", "val") - from props - where "val" is not null - ); - end case; -end; -$$ language plpgsql immutable; diff --git a/supabase/migrations/02_flowid.sql b/supabase/migrations/02_flowid.sql deleted file mode 100644 index 5fc48bd00a..0000000000 --- a/supabase/migrations/02_flowid.sql +++ /dev/null @@ -1,112 +0,0 @@ - -create domain flowid as macaddr8; -comment on domain flowid is ' -flowid is a montonic, time-ordered ID with gaps that fits within 64 bits. -We use macaddr8 as its underlying storage type because: - - 1) It''s stored as exactly 8 bytes, with the same efficiency as BIGINT. - 2) It has a flexible, convienient to_json() behavior that (crucially) - is loss-less by default when parsed in JavaScript. - -Postgres''s to_json() serializes BIGINT as a bare integer, -which is subject to silent rounding by many parsers when values -exceed 53 bits (as is common with flowid). - -The canonical flowid encoding is lower-case hexidecimal with each byte -separated by ":", which is what''s returned by Postgres & PostgREST. -Postgres (and PostgREST!) will accept any hex value of the correct -implied length, with bytes optionally separated by any arrangement -of ":" or "-". -'; - -create sequence internal.shard_0_id_sequence; - -create function internal.id_generator() -returns flowid as $$ -declare - -- This procedure generates unique 64-bit integers - -- with the following bit layout: - -- - -- 0b00000010100000101011010111111000100000101010100100011111100011100 - -- |-- Timestamp Millis --||-- SeqNo --||- Shard-| - -- - -- Estuary epoch is the first representable timestamp in generated IDs. - -- This could be zero, but subtracting |estuary_epoch| results in the - -- high bit being zero for the next ~34 years, - -- making ID representations equivalent for both signed and - -- unsigned 64-bit integers. - estuary_epoch bigint := 1600000000; - -- The id of this parallizable ID generation shard. - -- ID's generated inside of PostgreSQL always use |shard_id| zero. - -- We reserve other shard IDs for future parallized ID generation. - -- The allowed range is [0, 1024) (10 bits). - shard_id int := 0; - -- Sequence number is a monotonic tie-breaker for IDs generated - -- within the same millisecond. - -- The allowed range is [0, 8192) (13 bits). - seq_no bigint; - -- Current timestamp, as Unix millis since |estuary_epoch|. - now_millis bigint; -begin - -- We have 13 low bits of sequence ID, which allow us to generate - -- up to 8,192 unique IDs within each given millisecond. - select nextval('internal.shard_0_id_sequence') % 8192 into seq_no; - - select floor((extract(epoch from clock_timestamp()) - estuary_epoch) * 1000) into now_millis; - return lpad(to_hex((now_millis << 23) | (seq_no << 10) | (shard_id)), 16, '0')::flowid; -end; -$$ language plpgsql -security definer -; -comment on function internal.id_generator is ' -id_generator produces 64bit unique, non-sequential identifiers. They: - * Have fixed storage that''s 1/2 the size of a UUID. - * Have a monotonic generation order. - * Embed a wall-clock timestamp than can be extracted if needed. - * Avoid the leaky-ness of SERIAL id''s. - -Adapted from: https://rob.conery.io/2014/05/29/a-better-id-generator-for-postgresql/ -Which itself was inspired by http://instagram-engineering.tumblr.com/post/10853187575/sharding-ids-at-instagram -'; - --- Set id_generator as the DEFAULT value of a flowid whenever it's used in a table. -alter domain flowid set default internal.id_generator(); - - --- _model is not used directly, but is a model for other created tables. -create table internal._model ( - created_at timestamptz not null default now(), - detail text, - id flowid primary key not null, - updated_at timestamptz not null default now() -); - -comment on table internal._model is - 'Model table for the creation of other tables'; -comment on column internal._model.created_at is - 'Time at which the record was created'; -comment on column internal._model.detail is - 'Description of the record'; -comment on column internal._model.id is - 'ID of the record'; -comment on column internal._model.updated_at is - 'Time at which the record was last updated'; - --- _model_async is a model for other created tables that imply server-side operations. --- --- NOTE(johnny): Also add async tables to the `supabase_realtime` publication: --- alter publication supabase_realtime add table my_async_table; -create table internal._model_async ( - like internal._model including all, - - job_status jsonb_obj not null default '{"type":"queued"}', - logs_token uuid not null default gen_random_uuid() -); - -comment on table internal._model_async is - 'Model table for the creation of other tables representing a server-side operation'; -comment on column internal._model_async.job_status is - 'Server-side job executation status of the record'; -comment on column internal._model_async.logs_token is - 'Bearer token for accessing logs of the server-side operation'; - diff --git a/supabase/migrations/03_catalog-types.sql b/supabase/migrations/03_catalog-types.sql deleted file mode 100644 index bb51397478..0000000000 --- a/supabase/migrations/03_catalog-types.sql +++ /dev/null @@ -1,66 +0,0 @@ -create domain catalog_name as text - constraint "Must be a valid catalog name" - check (value ~ '^([[:alpha:][:digit:]\-_.]+/)+[[:alpha:][:digit:]\-_.]+$' and value is nfkc normalized); -comment on domain catalog_name is ' -catalog_name is a name within the Flow catalog namespace. - -Catalog names consist of Unicode-normalized (NFKC) letters, numbers, -"-", "_", and ".", with components separated by "/" and not ending in "/". - -For example: "acmeCo/anvils" or "acmeCo/products/TnT_v4", -but not "acmeCo//anvils/" or "acmeCo/some anvils". -'; - -create domain catalog_prefix as text - constraint "Must be a valid catalog prefix" - check (value ~ '^([[:alpha:][:digit:]\-_.]+/)+$' and value is nfkc normalized); -comment on domain catalog_prefix is ' -catalog_name is a prefix within the Flow catalog namespace. - -Catalog prefixes consist of Unicode-normalized (NFKC) letters, numbers, -"-", "_", and ".", with components separated by "/" and ending in a final "/". - -For example: "acmeCo/anvils/" or "acmeCo/products/TnT_v4/", -but not "acmeCo/anvils" or "acmeCo/some anvils". -'; - -create domain catalog_tenant as text - constraint "Must be a valid catalog tenant" - check (value ~ '^[[:alpha:][:digit:]\-_.]+/$' and value is nfkc normalized); -comment on domain catalog_tenant is ' -catalog_tenant is a prefix within the Flow catalog namespace -having exactly one top-level path component. - -Catalog tenants consist of Unicode-normalized (NFKC) letters, numbers, -"-", "_", and "." and ending in a final "/". - -For example: "acmeCo/" or "acmeCo.anvils/" or "acmeCo-TNT/", -but not "acmeCo" or "acmeCo/anvils/" or "acmeCo/TNT". -'; - -create type catalog_spec_type as enum ( - -- These correspond 1:1 with top-level maps of models::Catalog. - 'capture', - 'collection', - 'materialization', - 'test' -); - -comment on type catalog_spec_type is ' -Enumeration of Flow catalog specification types: -"capture", "collection", "materialization", or "test" -'; - -create function internal.notify_agent() returns trigger as $trigger$ -declare - payload text; -begin - -- Build the payload - payload := json_build_object('timestamp',CURRENT_TIMESTAMP,'table',TG_TABLE_NAME); - - -- Notify the channel - perform pg_notify('agent_notifications', payload); - - return null; -END; -$trigger$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/supabase/migrations/04_auth.sql b/supabase/migrations/04_auth.sql deleted file mode 100644 index 89d53e573b..0000000000 --- a/supabase/migrations/04_auth.sql +++ /dev/null @@ -1,212 +0,0 @@ --- Roles which are created by supabase: --- create role if not exists anon; --- create role if not exists authenticated; - --- A new supabase installation grants all in public to anon & authenticated. --- We elect to NOT do this, instead explicitly granting access to the tables --- and functions which uses should be able to access. -alter default privileges in schema public revoke all on tables from anon, authenticated; -alter default privileges in schema public revoke all on routines from anon, authenticated; -alter default privileges in schema public revoke all on sequences from anon, authenticated; - --- Provide API clients a way to determine their effective user_id. -create function auth_uid() -returns uuid as $$ - select auth.uid() -$$ language sql stable; -comment on function auth_uid is - 'auth_uid returns the user ID of the authenticated user'; - - --- Enumeration of capabilities that can be granted. -create type grant_capability as enum ( - 'x_00', - 'x_01', - 'x_02', - 'x_03', - 'x_04', - 'x_05', - 'x_06', - 'x_07', - 'x_08', - 'x_09', - 'read', -- Tag: 10 - 'x_11', - 'x_12', - 'x_13', - 'x_14', - 'x_15', - 'x_16', - 'x_17', - 'x_18', - 'x_19', - 'write', -- Tag: 20 - 'x_21', - 'x_22', - 'x_23', - 'x_24', - 'x_25', - 'x_26', - 'x_27', - 'x_28', - 'x_29', - 'admin' -- Tag: 30 -); -comment on type grant_capability is ' -grant_capability is an ordered enumeration of grant capabilities -bestowed upon a grantee by a grantor. Higher enumerated values -imply all of the capabilities of lower enum values. - -Enum values beginning with "x_" are placeholders for possible -future extension of the set of granted capabilities. - -A "read" capability allows a user or catalog specifications to -read from collections. - -A "write" capability allows a user or catalog specification to -write data into collections. - -The "admin" capability allows for creating, updating, and deleting -specifications. Unlike "read" or "write", this capability also recursively -grants the bearer all capabilities of the object_role. Put differently, -a user capable of changing a catalog specification is also granted the -capabilities which that specification itself uses to read and write data. -'; - - --- Grants of users to roles. -create table user_grants ( - like internal._model including all, - - user_id uuid references auth.users(id) not null, - object_role catalog_prefix not null, - capability grant_capability not null, - - unique(user_id, object_role) -); -alter table user_grants enable row level security; - --- Index that accelerates operator ^@ (starts-with) for combined_grants_ext view. -create index idx_user_grants_object_role_spgist on user_grants using spgist ((object_role::text)); - -comment on table user_grants is - 'Roles and capabilities that the user has been granted'; -comment on column user_grants.user_id is - 'User who has been granted a role'; -comment on column user_grants.object_role is - 'Role which is granted to the user'; -comment on column user_grants.capability is - 'Capability which is granted to the user'; - - --- Grants of roles to other roles. -create table role_grants ( - like internal._model including all, - - subject_role catalog_prefix not null, - object_role catalog_prefix not null, - capability grant_capability not null, - - unique(subject_role, object_role) -); -alter table role_grants enable row level security; - --- Index that accelerates operator ^@ (starts-with) for internal.auth_roles() and combined_grants_ext. -create index idx_role_grants_subject_role_spgist on role_grants using spgist ((subject_role::text)); -create index idx_role_grants_object_role_spgist on role_grants using spgist ((object_role::text)); - -comment on table role_grants is - 'Roles and capabilities that roles have been granted to other roles'; -comment on column role_grants.subject_role is - 'Role which has been granted a capability to another role'; -comment on column role_grants.object_role is - 'Role to which a capability has been granted'; -comment on column role_grants.capability is - 'Capability which is granted to the subject role'; - - -create function internal.user_roles( - target_user_id uuid, - min_capability grant_capability default 'x_00' -) -returns table (role_prefix catalog_prefix, capability grant_capability) as $$ - - with recursive - all_roles(role_prefix, capability) as ( - select object_role, capability from user_grants - where user_id = target_user_id - and capability >= min_capability - union - -- Recursive case: for each object_role granted as 'admin', - -- project through grants where object_role acts as the subject_role. - select role_grants.object_role, role_grants.capability - from role_grants, all_roles - where role_grants.subject_role ^@ all_roles.role_prefix - and role_grants.capability >= min_capability - and all_roles.capability = 'admin' - ) - select role_prefix, max(capability) from all_roles - group by role_prefix - order by role_prefix; - -$$ language sql stable; - - -create function auth_roles(min_capability grant_capability default 'x_00') -returns table (role_prefix catalog_prefix, capability grant_capability) as $$ - select role_prefix, capability from internal.user_roles(auth_uid(), min_capability) -$$ language sql stable security definer; -comment on function auth_roles is - 'auth_roles returns all roles and associated capabilities of the user'; - - --- Policy permissions for user_grants. -create policy "Users select user grants they admin or are the subject" - on user_grants as permissive for select - using (exists( - select 1 from auth_roles('admin') r where object_role ^@ r.role_prefix - ) or user_id = auth.uid()); -create policy "Users insert user grants they admin" - on user_grants as permissive for insert - with check (exists( - select 1 from auth_roles('admin') r where object_role ^@ r.role_prefix - )); -create policy "Users update user grants they admin" - on user_grants as permissive for update - using (exists( - select 1 from auth_roles('admin') r where object_role ^@ r.role_prefix - )); -create policy "Users delete user grants they admin or are the subject" - on user_grants as permissive for delete - using (exists( - select 1 from auth_roles('admin') r where object_role ^@ r.role_prefix - ) or user_id = auth.uid()); - -grant all on user_grants to authenticated; - - --- Policy permissions for role_grants. -create policy "Users select role grants where they admin the subject or object" - on role_grants as permissive for select - using (exists( - select 1 from auth_roles('admin') r - where (object_role ^@ r.role_prefix or subject_role ^@ r.role_prefix) - )); -create policy "Users insert role grants where they admin the object" - on role_grants as permissive for insert - with check (exists( - select 1 from auth_roles('admin') r where object_role ^@ r.role_prefix - )); -create policy "Users update role grants where they admin the object" - on role_grants as permissive for update - using (exists( - select 1 from auth_roles('admin') r where object_role ^@ r.role_prefix - )); -create policy "Users delete role grants where they admin the object or subject" - on role_grants as permissive for delete - using (exists( - select 1 from auth_roles('admin') r - where (object_role ^@ r.role_prefix or subject_role ^@ r.role_prefix) - )); - -grant all on role_grants to authenticated; diff --git a/supabase/migrations/05_logs.sql b/supabase/migrations/05_logs.sql deleted file mode 100644 index 33b5c4d0f9..0000000000 --- a/supabase/migrations/05_logs.sql +++ /dev/null @@ -1,35 +0,0 @@ - --- Log lines are newline-delimited outputs from server-side jobs. -create table internal.log_lines ( - log_line text not null, - logged_at timestamptz not null default now(), - stream text not null, - token uuid not null -); - -comment on table internal.log_lines is - 'Logs produced by server-side operations'; -comment on column internal.log_lines.log_line is - 'Logged line'; -comment on column internal.log_lines.token is - 'Bearer token which demarks and provides accesss to a set of logs'; -comment on column internal.log_lines.stream is - 'Identifier of the log stream within the job'; -comment on column internal.log_lines.logged_at is - 'Time at which the log was collected'; - -create index idx_logs_token_logged_at on internal.log_lines - using brin(token, logged_at) with (autosummarize = on); - - --- We cannot provide direct SELECT access to logs, but we *can* provide --- a view on logs so long as the user always provides a bearer token. -create function view_logs(bearer_token uuid) -returns setof internal.log_lines as $$ -begin - return query select * from internal.log_lines where internal.log_lines.token = bearer_token; -end; -$$ language plpgsql security definer; - -comment on function view_logs is - 'view_logs accepts a log bearer_token and returns its matching log lines'; diff --git a/supabase/migrations/06_connectors.sql b/supabase/migrations/06_connectors.sql deleted file mode 100644 index 86d1e0a743..0000000000 --- a/supabase/migrations/06_connectors.sql +++ /dev/null @@ -1,103 +0,0 @@ -create domain jsonb_internationalized_value as jsonb check ( - (value is null) OR -- This feels wrong, but without it the check constraint fails on nulls - (jsonb_typeof(value) = 'object' AND - (value->'en-US' IS NOT NULL)) -); -comment on domain jsonb_internationalized_value is - 'jsonb_internationalized_value is JSONB object which is required to at least have en-US internationalized values'; - --- Known connectors. -create table connectors ( - like internal._model including all, - - external_url text not null, - image_name text unique not null, - title jsonb_internationalized_value not null, - short_description jsonb_internationalized_value not null, - logo_url jsonb_internationalized_value not null, - recommended boolean not null default false, - oauth2_client_id text, - oauth2_client_secret text, - oauth2_injected_values jsonb_obj, - oauth2_spec jsonb_obj, - -- - constraint "image_name must be a container image without a tag" - check (image_name ~ '^(?:.+/)?([^:]+)$') -); --- Public, no RLS. - -comment on table connectors is ' -Connectors are Docker / OCI images which implement a standard protocol, -and allow Flow to interface with an external system for the capture -or materialization of data. -'; -comment on column connectors.external_url is - 'External URL which provides more information about the endpoint'; -comment on column connectors.image_name is - 'Name of the connector''s container (Docker) image, for example "ghcr.io/estuary/source-postgres"'; -comment on column connectors.oauth2_client_id is - 'oauth client id'; -comment on column connectors.oauth2_client_secret is - 'oauth client secret'; -comment on column connectors.oauth2_injected_values is - 'oauth additional injected values, these values will be made available in the credentials key of the connector, as well as when rendering oauth2_spec templates'; -comment on column connectors.oauth2_spec is - 'OAuth2 specification of the connector'; -comment on column public.connectors.logo_url is - 'The url for this connector''s logo image. Represented as a json object with IETF language tags as keys (https://en.wikipedia.org/wiki/IETF_language_tag), and urls as values'; -comment on column public.connectors.title is - 'The title of this connector. Represented as a json object with IETF language tags as keys (https://en.wikipedia.org/wiki/IETF_language_tag), and the title string as values'; -comment on column public.connectors.short_description is - 'A short description of this connector, at most a few sentences. Represented as a json object with IETF language tags as keys (https://en.wikipedia.org/wiki/IETF_language_tag), and the description string as values'; - --- don't expose details of oauth2 secret --- authenticated may select other columns for all connectors connectors. -grant select(id, detail, updated_at, created_at, image_name, external_url, title, short_description, logo_url, recommended, oauth2_client_id) on table connectors to authenticated; - --- TODO: make auto_discover_interval specific to captures -create table connector_tags ( - like internal._model_async including all, - - connector_id flowid not null references connectors(id), - documentation_url text, -- Job output. - endpoint_spec_schema json_obj, -- Job output. - image_tag text not null, - protocol text, -- Job output. - resource_spec_schema json_obj, -- Job output. - auto_discover_interval interval not null default '2h'::interval, - unique(connector_id, image_tag), - -- - constraint "image_tag must start with : (as in :latest) or @sha256:" - check (image_tag like ':%' or image_tag like '@sha256:') -); --- Public, no RLS. - -create trigger "Notify agent about changes to connector_tags" after insert or update on connector_tags -for each statement execute procedure internal.notify_agent(); - -comment on table connector_tags is ' -Available image tags (versions) of connectors. -Tags are _typically_ immutable versions, -but it''s possible to update the image digest backing a tag, -which is arguably a different version. -'; -comment on column connector_tags.connector_id is - 'Connector which this record is a tag of'; -comment on column connector_tags.documentation_url is - 'Documentation URL of the tagged connector'; -comment on column connector_tags.endpoint_spec_schema is - 'Endpoint specification JSON-Schema of the tagged connector'; -comment on column connector_tags.image_tag is - 'Image tag, in either ":v1.2.3", ":latest", or "@sha256:" form'; -comment on column connector_tags.protocol is - 'Protocol of the connector'; -comment on column connector_tags.resource_spec_schema is - 'Resource specification JSON-Schema of the tagged connector'; -comment on column connector_tags.auto_discover_interval is - 'Frequency at which to perform automatic discovery operations for captures, when autoDiscover is enabled'; - --- authenticated may select all connector_tags without restrictions. -grant select on table connector_tags to authenticated; - -create unique index idx_connector_tags_id_where_queued on connector_tags(id) - where job_status->>'type' = 'queued'; diff --git a/supabase/migrations/07_drafts.sql b/supabase/migrations/07_drafts.sql deleted file mode 100644 index 39faa7cfa8..0000000000 --- a/supabase/migrations/07_drafts.sql +++ /dev/null @@ -1,113 +0,0 @@ - --- Draft changesets of Flow specifications. -create table drafts ( - like internal._model including all, - - user_id uuid references auth.users(id) not null default auth.uid() -); -alter table drafts enable row level security; - -create policy "Users can access only their created drafts" - on drafts as permissive - using (user_id = auth.uid()); - -grant insert (detail) on drafts to authenticated; -grant update (detail) on drafts to authenticated; -grant select on drafts to authenticated; -grant delete on drafts to authenticated; - -comment on table drafts is - 'Draft change-sets of Flow catalog specifications'; -comment on column drafts.user_id is - 'User who owns this draft'; - -create index idx_drafts_user_id on drafts(user_id); - - --- Errors encountered within user drafts -create table draft_errors ( - draft_id flowid not null references drafts(id) on delete cascade, - scope text not null, - detail text not null -); -alter table draft_errors enable row level security; - -create policy "Users can access and delete errors of their drafts" - on draft_errors as permissive - using (draft_id in (select id from drafts)); -grant select, delete on draft_errors to authenticated; - -comment on table draft_errors is - 'Errors found while validating, testing or publishing a user draft'; -comment on column draft_errors.draft_id is - 'Draft which produed this error'; -comment on column draft_errors.scope is - 'Location scope of the error within the draft'; -comment on column draft_errors.detail is - 'Description of the error'; - -create index idx_draft_errors_draft_id on draft_errors(draft_id); - - --- Draft specifications which the user is working on. -create table draft_specs ( - like internal._model including all, - - draft_id flowid not null references drafts(id) on delete cascade, - catalog_name catalog_name not null, - unique (draft_id, catalog_name), - - expect_pub_id flowid default null, - spec json, - spec_type catalog_spec_type, - built_spec json, - validated json, - - constraint "spec and spec_type must be consistent" check ( - json_typeof(spec) is distinct from 'null' and (spec is null) = (spec_type is null) - ) -); -alter table draft_specs enable row level security; - -create policy "Users access their draft specs" - on draft_specs as permissive - using (draft_id in (select id from drafts)); -grant all on draft_specs to authenticated; - -comment on table draft_specs is - 'Proposed catalog specifications of a draft'; -comment on column draft_specs.draft_id is - 'Draft which this specification belongs to'; -comment on column draft_specs.catalog_name is - 'Catalog name of this specification'; -comment on column draft_specs.expect_pub_id is ' -Draft specifications may be drawn from a current live specification, -and in this case it''s recommended that expect_pub_id is also set to the -last_pub_id of that inititializing live specification. - -Or if there isn''t expected to be a live specification then -expect_pub_id can be the set to an explicit value of ''00:00:00:00:00:00:00:00'' -to represent that no live specification is expected to exist. - -Then when this draft is published, the publication will fail if the now-current -live specification has a different last_pub_id. This prevents inadvertent errors -where two users attempt to modify or create a catalog specification at the same time, -as the second user publication will fail rather than silently overwriting changes -made by the first user. - -When NULL, expect_pub_id has no effect. -'; -comment on column draft_specs.spec is ' -Spec is a serialized catalog specification. Its schema depends on its spec_type: -either CollectionDef, CaptureDef, MaterializationDef, DerivationDef, -or an array of TestStep from the Flow catalog schema. - -It may also be NULL, in which case `spec_type` must also be NULL -and the specification will be deleted when this draft is published. -'; -comment on column draft_specs.spec_type is - 'Type of this draft catalog specification'; -comment on column draft_specs.built_spec is - 'Built specification for this catalog'; -comment on column draft_specs.validated is - 'Serialized response from the connector Validate RPC as populated by a dry run of this draft specification'; diff --git a/supabase/migrations/08_discovers.sql b/supabase/migrations/08_discovers.sql deleted file mode 100644 index 5aef94f134..0000000000 --- a/supabase/migrations/08_discovers.sql +++ /dev/null @@ -1,45 +0,0 @@ - --- User-initiated discover operations, which upsert specifications into a draft. -create table discovers ( - like internal._model_async including all, - - capture_name catalog_name not null, - connector_tag_id flowid not null references connector_tags(id), - draft_id flowid not null references drafts(id) on delete cascade, - endpoint_config json_obj not null, - update_only boolean not null default false, - auto_publish boolean not null default false, - auto_evolve boolean not null default false -); -alter table discovers enable row level security; - -create trigger "Notify agent about changes to discover requests" after insert or update on discovers -for each statement execute procedure internal.notify_agent(); - -create policy "Users access their discovers" - on discovers as permissive - using (draft_id in (select id from drafts)); - -grant select on discovers to authenticated; -grant insert (capture_name, connector_tag_id, draft_id, endpoint_config, update_only) - on discovers to authenticated; - -comment on table discovers is - 'User-initiated connector discovery operations'; -comment on column discovers.capture_name is - 'Intended name of the capture produced by this discover'; -comment on column discovers.connector_tag_id is - 'Tagged connector which is used for discovery'; -comment on column discovers.draft_id is - 'Draft to be populated by this discovery operation'; -comment on column discovers.endpoint_config is - 'Endpoint configuration of the connector. May be protected by sops'; -comment on column discovers.update_only is ' -If true, this operation will draft updates to existing bindings and their -target collections but will not add new bindings or collections.'; -comment on column discovers.auto_publish is -'whether to automatically publish the results of the discover, if successful'; -comment on column discovers.auto_evolve is -'whether to automatically create an evolutions job if the automatic publication -fails due to incompatible collection schemas. This determines the value of `auto_evolve` -in the publications table when inserting a new row as a result of this discover.'; diff --git a/supabase/migrations/09_publications.sql b/supabase/migrations/09_publications.sql deleted file mode 100644 index 6a90357e2f..0000000000 --- a/supabase/migrations/09_publications.sql +++ /dev/null @@ -1,189 +0,0 @@ - --- publications are operations that test (if dry_run) or test and then publish --- a draft. We retain publication rows for a limited period of time, --- but continue to use their unique IDs within the longer-lived audit log --- of published specifications. -create table publications ( - like internal._model_async including all, - - user_id uuid references auth.users(id) not null default auth.uid(), - draft_id flowid not null, - dry_run bool not null default false, - auto_evolve boolean not null default false -); -alter table publications enable row level security; - -create trigger "Notify agent about changes to publication" after insert or update on publications -for each statement execute procedure internal.notify_agent(); - --- We don't impose a foreign key on drafts, because a publication --- operation audit log may stick around much longer than the draft does. -create policy "Users can access only their initiated publish operations" - on publications as permissive for select - using (user_id = auth.uid()); -create policy "Users can insert publications from permitted drafts" - on publications as permissive for insert - with check (draft_id in (select id from drafts)); - -grant select on publications to authenticated; -grant insert (draft_id, dry_run, detail) on publications to authenticated; - -comment on table publications is - 'Publications are operations which test and publish drafts into live specifications'; -comment on column publications.user_id is - 'User who created the publication'; -comment on column publications.draft_id is - 'Draft which is published'; -comment on column publications.dry_run is - 'A dry-run publication will test and verify a draft, but doesn''t publish into live specifications'; -comment on column publications.auto_evolve is - 'Whether to automatically handle schema evolution if the publication fails due to incompatible collections. - If true, then an evolutions job will be created automatically if needed, and the results will be published again.'; - - --- Live (current) specifications of the catalog. -create table live_specs ( - like internal._model including all, - - -- catalog_name is the conceptual primary key, but we use flowid as - -- the literal primary key for consistency and join performance. - catalog_name catalog_name not null, - connector_image_name text, - connector_image_tag text, - last_build_id flowid not null, - last_pub_id flowid not null, - reads_from text[], - spec json, - spec_type catalog_spec_type, - writes_to text[], - built_spec json, - -- JSON specs are encoded into the database with leading spaces which must be trimmed to compute - -- an accurate md5. - md5 text generated always as (md5(trim(spec::text))) stored, - - constraint "spec and spec_type must be consistent" check ( - json_typeof(spec) is distinct from 'null' and (spec is null) = (spec_type is null) - ), - unique (catalog_name) -); -alter table live_specs enable row level security; - --- Index that accelerates operator ^@ (starts-with) for live_specs_ext view. -create index idx_live_specs_catalog_name_spgist on live_specs using spgist ((catalog_name::text)); - -create index idx_live_specs_spec_type on live_specs (spec_type); -create index idx_live_specs_updated_at on live_specs (updated_at desc nulls last); - -create policy "Users must be read-authorized to the specification catalog name" - on live_specs as permissive for select - using (exists( - select 1 from auth_roles('read') r where catalog_name ^@ r.role_prefix - )); -grant select on live_specs to authenticated; - -comment on table live_specs is - 'Live (in other words, current) catalog specifications of the platform'; -comment on column live_specs.catalog_name is - 'Catalog name of this specification'; -comment on column live_specs.connector_image_name is - 'OCI (Docker) connector image name used by this specification'; -comment on column live_specs.connector_image_tag is - 'OCI (Docker) connector image tag used by this specification'; -comment on column live_specs.last_build_id is ' -Last publication ID under which this specification was built and activated -into the data-plane, even if it was not necessarily updated. - -A specification may be included in a publication which did not directly -change it simply because of its connection to other specifications which -were part of that publication: Flow identifies connected specifications -in order to holistically verify and test their combined behaviors. -'; -comment on column live_specs.last_pub_id is - 'Last publication ID which updated this specification'; -comment on column live_specs.reads_from is ' -List of collections read by this catalog task specification, -or NULL if not applicable to this specification type. -These adjacencies are also indexed within `live_spec_flows`. -'; -comment on column live_specs.spec is - 'Serialized catalog specification, or NULL if this specification is deleted'; -comment on column live_specs.spec_type is - 'Type of this catalog specification, or NULL if this specification is deleted'; -comment on column live_specs.writes_to is ' -List of collections written by this catalog task specification, -or NULL if not applicable to this specification type. -These adjacencies are also indexed within `live_spec_flows`. -'; -comment on column live_specs.built_spec is - 'Built specification for this catalog'; - - --- Data-flows between live specifications. -create table live_spec_flows ( - source_id flowid not null references live_specs(id), - target_id flowid not null references live_specs(id), - flow_type catalog_spec_type not null -); -alter table live_spec_flows enable row level security; - -create policy "Users must be authorized to referenced specifications" - on live_spec_flows as permissive for select - using ( - source_id in (select id from live_specs) and - target_id in (select id from live_specs) - ); -grant select on live_specs to authenticated; - -create unique index idx_live_spec_flows_forward - on live_spec_flows(source_id, target_id) include (flow_type); -create unique index idx_live_spec_flows_reverse - on live_spec_flows(target_id, source_id) include (flow_type); - -comment on table live_spec_flows is - 'Join table of directed data-flows between live specifications'; -comment on column live_spec_flows.source_id is - 'Specification from which data originates'; -comment on column live_spec_flows.target_id is - 'Specification to which data flows'; - - --- Published specifications which record the changes made to specs over time. -create table publication_specs ( - live_spec_id flowid references live_specs(id) not null, - pub_id flowid not null, - primary key (live_spec_id, pub_id), - - detail text, - published_at timestamptz not null default now(), - spec json, - spec_type catalog_spec_type, - user_id uuid references auth.users(id) not null default auth.uid(), - - constraint "spec and spec_type must be consistent" check ( - json_typeof(spec) is distinct from 'null' and (spec is null) = (spec_type is null) - ) -); -alter table draft_specs enable row level security; - -create policy "Users must be read-authorized to the specification catalog name" - on publication_specs as permissive for select - using (live_spec_id in (select id from live_specs)); -grant select on publication_specs to authenticated; - - -comment on table publication_specs is ' -publication_specs details the publication history of the `live_specs` catalog. -Each change to a live specification is recorded into `publication_specs`. -'; -comment on column publication_specs.live_spec_id is - 'Live catalog specification which was published'; -comment on column publication_specs.pub_id is - 'Publication ID which published to the catalog specification'; -comment on column publication_specs.spec_type is - 'Type of the published catalog specification, or NULL if this was a deletion'; -comment on column publication_specs.spec is ' -Catalog specification which was published by this publication, -or NULL if this was a deletion. -'; -comment on column publication_specs.user_id is - 'User who performed this publication.'; diff --git a/supabase/migrations/10_spec_ext.sql b/supabase/migrations/10_spec_ext.sql deleted file mode 100644 index 24500619d7..0000000000 --- a/supabase/migrations/10_spec_ext.sql +++ /dev/null @@ -1,200 +0,0 @@ -/* -This source contains extended metadata views for a number of tables. -We adopt a convention of always naming these tables `${table}_ext`, -and including all columns of the base table with their original names. - -IMPORTANT: BE CAREFUL with "grant select" on views -- you MUST inline -authorization checks. By default, prefer to change the owner to `authenticated`. -Reason: when created, views are owned by the "postgres" user, to which -row-level security policies don't apply. "grant select" then grants to -`authenticated` the same access that "postgres" has. Changing the owner to -`authenticated` causes the view to be evaluated under their RLS policies. -*/ - -create type user_profile as ( - user_id uuid, - email text, - full_name text, - avatar_url text -); - -create view internal.user_profiles as - select - id as user_id, - email, - coalesce(raw_user_meta_data->>'full_name', raw_user_meta_data->>'name') as full_name, - coalesce(raw_user_meta_data->>'picture', raw_user_meta_data->>'avatar_url') as avatar_url from auth.users; - -grant select on table internal.user_profiles to authenticated; -grant all on table internal.user_profiles to postgres; - --- Provide API clients a way to map a User ID to a user profile. --- `bearer_user_id` is a UUID ID of the auth.users table and is treated as a bearer token: --- Anyone able to identify a UUID is able to retrieve their profile. -create function view_user_profile(bearer_user_id uuid) -returns user_profile as $$ - select - user_id, - email, - full_name, - avatar_url - from internal.user_profiles where user_id = bearer_user_id; -$$ language sql stable security definer; - -comment on function view_user_profile is - 'view_user_profile returns the profile of the given user ID'; - - --- Extended view of combined `user_grants` and `role_grants`. -create view combined_grants_ext as -with admin_roles as ( - -- Extract into CTE so it's evaluated once, not twice. - -- This is only required because of the union, which produces - -- entirely separate evaluation nodes within the query plan - -- that naievely don't share the auth_roles() result. - select role_prefix from auth_roles('admin') -) -select - g.capability, - g.created_at, - g.detail, - g.id, - g.object_role, - g.updated_at, - -- - g.subject_role, - -- - null as user_avatar_url, - null as user_email, - null as user_full_name, - null as user_id -from role_grants g -where g.id in ( - -- User must admin subject or object role. Compare to select RLS policy. - select g.id from admin_roles r, role_grants g - where g.subject_role ^@ r.role_prefix or g.object_role ^@ r.role_prefix -) -union all -select - g.capability, - g.created_at, - g.detail, - g.id, - g.object_role, - g.updated_at, - -- - null as subject_role, - -- - u.avatar_url as user_avatar_url, - u.email as user_email, - u.full_name as user_full_name, - g.user_id as user_id -from user_grants g -left outer join internal.user_profiles u on u.user_id = g.user_id -where g.id in ( - -- User must admin object role or be the user. Compare to select RLS policy. - select g.id from admin_roles r, user_grants g - where g.user_id = auth.uid() or g.object_role ^@ r.role_prefix -) -; --- combined_grants_ext includes its own authorization checks. -grant select on combined_grants_ext to authenticated; - -comment on view combined_grants_ext is - 'Combined view of `role_grants` and `user_grants` extended with user metadata'; - - --- Extended view of live catalog specifications. -create view live_specs_ext as -select - l.*, - c.external_url as connector_external_url, - c.id as connector_id, - c.title as connector_title, - c.short_description as connector_short_description, - c.logo_url as connector_logo_url, - c.recommended as connector_recommended, - t.id as connector_tag_id, - t.documentation_url as connector_tag_documentation_url, - p.detail as last_pub_detail, - p.user_id as last_pub_user_id, - u.avatar_url as last_pub_user_avatar_url, - u.email as last_pub_user_email, - u.full_name as last_pub_user_full_name -from live_specs l -left outer join publication_specs p on l.id = p.live_spec_id and l.last_pub_id = p.pub_id -left outer join connectors c on c.image_name = l.connector_image_name -left outer join connector_tags t on c.id = t.connector_id and l.connector_image_tag = t.image_tag -left outer join internal.user_profiles u on u.user_id = p.user_id -where l.id in ( - -- User must admin catalog_name. Compare to select RLS policy. - select l.id from auth_roles('read') r, live_specs l - where l.catalog_name ^@ r.role_prefix -) -; --- live_specs_ext includes its own authorization checks. -grant select on live_specs_ext to authenticated; - -comment on view live_specs_ext is - 'View of `live_specs` extended with metadata of its last publication'; - - --- Extended view of specification publication history. -create view publication_specs_ext as -select - p.*, - l.catalog_name, - l.last_pub_id, - u.email as user_email, - u.full_name as user_full_name, - u.avatar_url as user_avatar_url -from publication_specs p -join live_specs l on p.live_spec_id = l.id, -lateral view_user_profile(p.user_id) u -; - -alter view publication_specs_ext set (security_invoker = on); -grant select on publication_specs_ext to authenticated; - -comment on view publication_specs_ext is - 'View of `publication_specs` extended with metadata of its user'; - - --- Extended view of drafts. -create view drafts_ext as -select - d.*, - s.num_specs -from drafts d, -lateral (select count(*) num_specs from draft_specs where draft_id = d.id) s -; - -alter view drafts_ext set (security_invoker = on); -grant select on drafts_ext to authenticated; - -comment on view drafts_ext is - 'View of `drafts` extended with metadata of its specifications'; - - --- Extended view of user draft specifications. -create view draft_specs_ext as -select - d.*, - l.last_pub_detail, - l.last_pub_id, - l.last_pub_user_id, - l.last_pub_user_avatar_url, - l.last_pub_user_email, - l.last_pub_user_full_name, - l.spec as live_spec, - l.spec_type as live_spec_type -from draft_specs d -left outer join live_specs_ext l - on d.catalog_name = l.catalog_name -; - -alter view draft_specs_ext set (security_invoker = on); -grant select on draft_specs_ext to authenticated; - -comment on view draft_specs_ext is - 'View of `draft_specs` extended with metadata of its live specification'; diff --git a/supabase/migrations/11_stats.sql b/supabase/migrations/11_stats.sql deleted file mode 100644 index 0004f0d8aa..0000000000 --- a/supabase/migrations/11_stats.sql +++ /dev/null @@ -1,84 +0,0 @@ --- This migration creates the tables needed for materialization --- of task stats into the control plane. - -create type grain as enum ('monthly', 'daily', 'hourly'); - --- The `catalog_stats` table is _not_ identical to what the connector would have created. --- They have slightly different column types to make things a little more ergonomic and consistent. - -create table catalog_stats ( - catalog_name catalog_name not null, - grain text not null, - ts timestamptz not null, - bytes_written_by_me bigint not null default 0, - docs_written_by_me bigint not null default 0, - bytes_read_by_me bigint not null default 0, - docs_read_by_me bigint not null default 0, - bytes_written_to_me bigint not null default 0, - docs_written_to_me bigint not null default 0, - bytes_read_from_me bigint not null default 0, - docs_read_from_me bigint not null default 0, - warnings integer not null default 0, - errors integer not null default 0, - failures integer not null default 0, - flow_document json not null, - primary key (catalog_name, grain, ts) -); -alter table catalog_stats enable row level security; - -create policy "Users must be authorized to the catalog name" - on catalog_stats as permissive for select - using (exists( - select 1 from auth_roles('read') r where catalog_name ^@ r.role_prefix - )); -grant select on catalog_stats to authenticated; - -comment on table catalog_stats is - 'Statistics for Flow catalogs'; -comment on column catalog_stats.grain is ' -Time grain that stats are summed over. - -One of "monthly", "daily", or "hourly". -'; -comment on column catalog_stats.bytes_written_by_me is - 'Bytes written by this catalog, summed over the time grain.'; -comment on column catalog_stats.docs_written_by_me is - 'Documents written by this catalog, summed over the time grain.'; -comment on column catalog_stats.bytes_read_by_me is - 'Bytes read by this catalog, summed over the time grain.'; -comment on column catalog_stats.docs_read_by_me is - 'Documents read by this catalog, summed over the time grain.'; -comment on column catalog_stats.bytes_written_to_me is - 'Bytes written to this catalog, summed over the time grain.'; -comment on column catalog_stats.docs_written_to_me is - 'Documents written to this catalog, summed over the time grain.'; -comment on column catalog_stats.bytes_read_from_me is - 'Bytes read from this catalog, summed over the time grain.'; -comment on column catalog_stats.docs_read_from_me is - 'Documents read from this catalog, summed over the time grain.'; -comment on column catalog_stats.ts is ' -Timestamp indicating the start time of the time grain. - -Monthly grains start on day 1 of the month, at hour 0 and minute 0. -Daily grains start on the day, at hour 0 and minute 0. -Hourly grains start on the hour, at minute 0. -'; -comment on column catalog_stats.flow_document is - 'Aggregated statistics document for the given catalog name and grain'; - -do $$ -begin - if not exists (select from pg_catalog.pg_roles where rolname = 'stats_loader') then - create role stats_loader with login password 'stats_loader_password' bypassrls; - end if; - grant stats_loader to postgres; - grant create on schema public to stats_loader; -end -$$; - --- stats_loader loads directly to the catalog_stats table. Postgres routes records to the correct --- partition based on the catalog name. We make catalog_stats owned by stats_loader instead of --- postgres to allow for new materializations to be applied for each tenant with catalog_stats as --- the target table. Materialization application will attempt to add comments to the target table & --- columns, and this will fail unless the table is owned by the acting user. -alter table catalog_stats owner to stats_loader; diff --git a/supabase/migrations/12_storage.sql b/supabase/migrations/12_storage.sql deleted file mode 100644 index 4f31318eea..0000000000 --- a/supabase/migrations/12_storage.sql +++ /dev/null @@ -1,23 +0,0 @@ - --- Storage mappings of catalog prefixes. -create table storage_mappings ( - like internal._model including all, - - catalog_prefix catalog_prefix unique not null, - spec json not null -); -alter table storage_mappings enable row level security; - -create policy "Users must be authorized to the specification catalog prefix" - on storage_mappings as permissive for select - using (exists( - select 1 from auth_roles('read') r where catalog_prefix ^@ r.role_prefix - )); -grant select on storage_mappings to authenticated; - -comment on table storage_mappings is - 'Storage mappings which are applied to published specifications'; -comment on column storage_mappings.catalog_prefix is - 'Catalog prefix which this storage mapping prefixes'; -comment on column storage_mappings.spec is - 'Specification of this storage mapping'; \ No newline at end of file diff --git a/supabase/migrations/13_auth_refs.sql b/supabase/migrations/13_auth_refs.sql deleted file mode 100644 index 613c22c020..0000000000 --- a/supabase/migrations/13_auth_refs.sql +++ /dev/null @@ -1,53 +0,0 @@ --- TODO(johnny): These views are particularly experimental and are likely to change. - -/* --- View which identifies live specifications that are missing --- a required write authorization to a referant. -create view internal.missing_write_auth as -select - src.id as sub_id, - src.catalog_name as sub_name, - src.spec_type as sub_type, - tgt.id as obj_id, - tgt.catalog_name as obj_name, - tgt.spec_type as obj_type -from live_specs src -join live_spec_flows e on src.spec_type in ('capture', 'test') and src.id = e.source_id -join live_specs tgt on e.target_id = tgt.id -where not exists( - select 1 from role_grants - where starts_with(src.catalog_name, subject_role) and - starts_with(tgt.catalog_name, object_role) and - capability >= 'write' -); - --- View which identifies live specifications that are missing --- a required read authorization to a referant. -create view internal.missing_read_auth as -select - src.id as obj_id, - src.catalog_name as obj_name, - src.spec_type as obj_type, - tgt.id as sub_id, - tgt.catalog_name as sub_name, - tgt.spec_type as sub_type -from live_specs src -join live_spec_flows e on src.spec_type = 'collection' and src.id = e.source_id -join live_specs tgt on e.target_id = tgt.id -where not exists( - select 1 from role_grants - where starts_with(src.catalog_name, object_role) and - starts_with(tgt.catalog_name, subject_role) and - capability >= 'read' -); - --- View which identifies live specifications that are missing --- a required read or write authorization to a referant. -create view internal.missing_auth as -select sub_id, sub_name, sub_type, obj_id, obj_name, obj_type, true as write -from internal.missing_write_auth -union all -select sub_id, sub_name, sub_type, obj_id, obj_name, obj_type, false -from internal.missing_read_auth -; -*/ \ No newline at end of file diff --git a/supabase/migrations/14_gateway_auth.sql b/supabase/migrations/14_gateway_auth.sql deleted file mode 100644 index 3a41496551..0000000000 --- a/supabase/migrations/14_gateway_auth.sql +++ /dev/null @@ -1,87 +0,0 @@ --- Keys used to sign/verify gateway auth tokens. -create table internal.gateway_auth_keys ( - like internal._model including all, - -- Key used to sign JWTs - secret_key text -); - -insert into internal.gateway_auth_keys (secret_key, detail) values ( - 'supersecret', 'Used for development only. This value will be changed manually when deployed to production.' -); - - - --- Addresses of deployed data plane gateways. As we deploy into multiple --- AZs/Regions, we can direct a caller to the appropriate Gateway for accessing --- data in a region-aware way. -create table internal.gateway_endpoints ( - like internal._model including all, - name text, - url text -); - -insert into internal.gateway_endpoints (name, url, detail) values ( - 'local', 'https://localhost:28318/', 'Used for development only. This value will be changed manually when deployed to production.' -); - - - --- Returns the most appropriate gateway url. For now, there should only be one. -create function internal.gateway_endpoint_url() -returns text as $$ - - select url - from internal.gateway_endpoints - limit 1 - -$$ language sql stable security definer; - - - --- Grabs the secret signing key and signs the object. -create function internal.sign_jwt(obj json) -returns text as $$ - - select sign(obj, secret_key::text) - from internal.gateway_auth_keys - limit 1 - -$$ language sql stable security definer; - -create function gateway_auth_token(variadic prefixes text[]) -returns table (token text, gateway_url text) as $$ -declare - -- The number of distinct prefixes (i.e. scopes) that were requested. - requested_prefixes int := (select count(distinct p) from unnest(prefixes) p); - -- The distinct prefixes, filtered by whether or not they are authorized. - authorized_prefixes text[]; -begin - - select array_agg(distinct p) into authorized_prefixes - from - unnest(prefixes) as p - join auth_roles() as r on starts_with(p, r.role_prefix); - - -- authorized_prefixes will be null when _none_ of the requested prefixes are authorized. - -- In that case the array_length comparison won't work, so we need an explicit null check. - if authorized_prefixes is null or array_length(authorized_prefixes, 1) != requested_prefixes then - -- errcode 28000 causes potgrest 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 all of the requested scopes' using errcode = 28000; - end if; - - return query select internal.sign_jwt( - json_build_object( - 'exp', trunc(extract(epoch from (now() + interval '1 hour'))), - 'iat', trunc(extract(epoch from (now()))), - 'operation', 'read', - 'prefixes', authorized_prefixes, - 'sub', auth_uid() - ) - ) as token, internal.gateway_endpoint_url() as gateway_url; -end; -$$ language plpgsql stable security definer; - -comment on function gateway_auth_token is - 'gateway_auth_token returns a jwt that can be used with the Data Plane Gateway to interact directly with Gazette RPCs.'; diff --git a/supabase/migrations/15_directives.sql b/supabase/migrations/15_directives.sql deleted file mode 100644 index d04144cd7c..0000000000 --- a/supabase/migrations/15_directives.sql +++ /dev/null @@ -1,207 +0,0 @@ - - -create table directives ( - like internal._model including all, - - catalog_prefix catalog_prefix not null, - uses_remaining bigint, - spec jsonb_obj not null, - token uuid unique default gen_random_uuid(), - - constraint "spec must have a string property `type`" check ( - jsonb_typeof(spec->'type') is not distinct from 'string') -); -alter table directives enable row level security; - -create policy "Users can access and change directives which they administer" - on directives as permissive - using (exists( - select 1 from auth_roles('admin') r where catalog_prefix ^@ r.role_prefix - )); - -grant all on directives to authenticated; - -create index idx_directives_catalog_prefix on directives - (catalog_prefix text_pattern_ops); - - -comment on table directives is ' -Directives are scoped operations that users may elect to apply. -For example, a directive might grant access to a specific catalog namespace, -or provision the setup of a new organization. - -In general these operations require administrative priviledge that the user -does not directly have. The directive mechanism thus enables a user to have a -priviledged operation be applied on their behalf in a self-service fashion. - -The types of operations supported by directives are open ended, -but each generally has a well-defined (but parameterizable) scope, -and may also be subject to additional server-side verification checks. - -To apply a given directive a user must know its current token, which is -a secret credential that''s typically exchanged through another channel -(such as Slack, or email). The user then creates a corresponding entry in -applied_directives with accompanying user claims. -'; -comment on column directives.catalog_prefix is ' -Catalog prefix which contains the directive. - -Operations undertaken by a directive are scoped within the catalog prefix, -and a user must admin the named prefix in order to admin its directives. -'; -comment on column directives.uses_remaining is ' -The maximum number of times that this directive may be applied. -This value gets decremented each time the directive is applied. -Once it reaches 0, future attempts to apply the directive will fail. -A null here means that there is no limit. -'; -comment on column directives.spec is ' -Specification of the directive. - -Specification documents must have a string `type` property which defines -the directive type. This type defines the meaning of the remainder of the -specification document. -'; -comment on column directives.token is ' -Bearer token which is presented by a user to access and apply a directive. -'; - -create table applied_directives ( - like internal._model_async including all, - - directive_id flowid references directives(id) not null, - user_id uuid references auth.users(id) not null default auth.uid(), - user_claims json_obj -); -alter table applied_directives enable row level security; - -create trigger "Notify agent of applied directive" after insert or update on applied_directives -for each statement execute procedure internal.notify_agent(); - -create policy "Users can access only their applied directives" - on applied_directives as permissive - using (user_id = auth.uid()); - -grant select on applied_directives to authenticated; -grant update (user_claims) on applied_directives to authenticated; -grant delete on applied_directives to authenticated; - -create policy "Users may select directives which they have applied" - on directives as permissive for select - using (id in (select directive_id from applied_directives)); - -comment on table applied_directives is ' -Directives which are being or have been applied by the user. - -Users begin to apply a directive by exchanging its bearer token, which creates -a new applied_directives row. Then, upon supplying user_claims which further -parameterize the operation, the directive is validated and applied with the -user''s claims. -'; -comment on column applied_directives.directive_id is - 'Directive which is being applied'; -comment on column applied_directives.user_id is - 'User on whose behalf the directive is being applied'; -comment on column applied_directives.user_claims is ' -User-supplied claims which parameterize the directive''s evaluation. - -User claims are initially null when an applied directive is first created, -and must be updated by the user for evaluation of the directive to begin. -'; - -create function internal.on_applied_directives_update() -returns trigger as $$ -begin - if OLD.job_status->>'type' = 'success' then - raise 'Cannot modify an applied directive which has completed' - using errcode = 'check_violation'; - end if; - - -- Clear a prior failed application, allowing the user to retry. - if OLD.user_claims::text is distinct from NEW.user_claims::text then - NEW.job_status = '{"type":"queued"}'; - end if; - - return NEW; -end -$$ language 'plpgsql'; - -create trigger "Verify update of applied directives" - before update on applied_directives - for each row - execute function internal.on_applied_directives_update(); - - -create function internal.on_applied_directives_delete() -returns trigger as $$ -begin - if OLD.job_status->>'type' = 'success' then - raise 'Cannot delete an applied directive which has completed' - using errcode = 'check_violation'; - end if; - - return OLD; -end -$$ language 'plpgsql'; - -create trigger "Verify delete of applied directives" - before delete on applied_directives - for each row - execute function internal.on_applied_directives_delete(); - - --- Users must present the current bearer token of a directive in order to --- apply it, and cannot directly create rows in `applied_directives` even if --- they know the directive_id, as we consider the flowid to be insecure. -create type exchanged_directive as ( - directive directives, - applied_directive applied_directives -); - -create function exchange_directive_token(bearer_token uuid) -returns exchanged_directive as $$ -declare - directive_row directives; - applied_row applied_directives; -begin - - -- Note that uses_remaining could be null, and in that case `uses_remaining - 1` - -- would also evaluate to null. This means that we don't actually update - -- uses_remaining here if the current value is null. - -- We also intentionally leave the bearer_token in place when uses_remaining - -- drops to 0, because it's possible that something may come along and - -- increase uses_remaining again. - update directives - set uses_remaining = uses_remaining - 1 - where directives.token = bearer_token - returning * into directive_row; - - if not found then - raise 'Bearer token % is not valid', bearer_token - using errcode = 'check_violation'; - end if; - - if directive_row.uses_remaining is not null and directive_row.uses_remaining < 0 then - raise 'System quota has been reached, please contact support@estuary.dev in order to proceed.' - using errcode = 'check_violation'; - end if; - - insert into applied_directives (directive_id, user_id) - values (directive_row.id, auth.uid()) - returning * into applied_row; - - return (directive_row, applied_row); -end; -$$ language plpgsql security definer; - -comment on function exchange_directive_token is ' -exchange_directive_token allows a user to turn in a directive bearer token -and, in exchange, create an application of that directive. - -If the supplied token is valid then a new row is created in `applied_directives`. -The user must next update it with their supplied claims. - -Having applied a directive through its token, the user is now able to view -the directive. As a convience, this function also returns the directive -along with the newly-created applied_directive row. -'; \ No newline at end of file diff --git a/supabase/migrations/16_tenants.sql b/supabase/migrations/16_tenants.sql deleted file mode 100644 index 5881354b4e..0000000000 --- a/supabase/migrations/16_tenants.sql +++ /dev/null @@ -1,61 +0,0 @@ - -create table tenants ( - like internal._model including all, - - -- TODO(johnny): In the future, we expect to hang billing - -- and data-plane assignment onto this record. - tenant catalog_tenant unique not null, - - tasks_quota integer not null default 10, - collections_quota integer not null default 500 -); -alter table tenants enable row level security; - -create policy "Users must be authorized to their catalog tenant" - on tenants as permissive for select - using (exists( - select 1 from auth_roles('admin') r where tenant ^@ r.role_prefix - )); -grant select on tenants to authenticated; - -comment on table tenants is ' -A tenant is the top-level unit of organization in the Flow catalog namespace. -'; -comment on column tenants.tenant is - 'Catalog tenant identified by this record'; - - -create table internal.illegal_tenant_names ( - name catalog_tenant unique not null primary key -); - -comment on table internal.illegal_tenant_names is - 'Illegal tenant names which are not allowed to be provisioned by users'; - -create function internal.update_support_role() returns trigger as $trigger$ -begin - insert into role_grants ( - detail, - subject_role, - object_role, - capability - ) - select - 'Automagically grant support role access to new tenant', - 'estuary_support/', - tenants.tenant, - 'admin' - from tenants - left join role_grants on - role_grants.object_role = tenants.tenant and - role_grants.subject_role = 'estuary_support/' - where role_grants.id is null and - tenants.tenant not in ('ops/', 'estuary/'); - - return null; -END; -$trigger$ LANGUAGE plpgsql; - -create trigger "Grant support role access to tenants" -after insert on tenants -for each statement execute function internal.update_support_role(); diff --git a/supabase/migrations/17_refresh_tokens.sql b/supabase/migrations/17_refresh_tokens.sql deleted file mode 100644 index 81b922788f..0000000000 --- a/supabase/migrations/17_refresh_tokens.sql +++ /dev/null @@ -1,129 +0,0 @@ --- Refresh tokens used to generate access tokens -create table refresh_tokens ( - like internal._model including all, - user_id uuid references auth.users(id) not null, - multi_use boolean default false, - valid_for interval not null, - uses int default 0, - hash text not null -); - -alter table refresh_tokens enable row level security; - -create policy "Users can access their own refresh tokens" - on refresh_tokens as permissive - using (user_id = auth.uid()); - -grant select(id, created_at, detail, updated_at, user_id, multi_use, valid_for, uses) on refresh_tokens to authenticated; -grant update(detail, valid_for, multi_use) on refresh_tokens to authenticated; -grant delete on refresh_tokens to authenticated; - --- Create a new refresh_token -create function create_refresh_token(multi_use boolean, valid_for interval, detail text default null) -returns json as $$ -declare - secret text; - refresh_token_row refresh_tokens; -begin - secret = gen_random_uuid(); - - insert into refresh_tokens (detail, user_id, multi_use, valid_for, hash) - values ( - detail, - auth_uid(), - multi_use, - valid_for, - crypt(secret, gen_salt('bf')) - ) returning * into refresh_token_row; - - return json_build_object( - 'id', refresh_token_row.id, - 'secret', secret - ); -commit; -end -$$ language plpgsql volatile security definer; - -comment on function create_refresh_token is ' -Create a new refresh token which can then be used to generate an access token using `generate_access_token` rpc. -'; - --- Returns the secret used for signing JWT tokens, with a default value for --- local env, taken from https://github.com/supabase/supabase-js/issues/25#issuecomment-1019935888 -create function internal.access_token_jwt_secret() -returns text as $$ - - select coalesce(current_setting('app.settings.jwt_secret', true), 'super-secret-jwt-token-with-at-least-32-characters-long') limit 1 - -$$ language sql stable; - -create function generate_access_token(refresh_token_id flowid, secret text) -returns json as $$ -declare - rt refresh_tokens; - rt_new_secret text; - access_token text; -begin - - select * into rt from refresh_tokens where - refresh_tokens.id = refresh_token_id; - - if not found then - raise 'could not find refresh_token with the given `refresh_token_id`'; - end if; - - if rt.hash <> crypt(secret, rt.hash) then - raise 'invalid secret provided'; - end if; - - if (rt.updated_at + rt.valid_for) < now() then - raise 'refresh_token has expired.'; - end if; - - select sign(json_build_object( - 'exp', trunc(extract(epoch from (now() + interval '1 hour'))), - 'iat', trunc(extract(epoch from (now()))), - 'sub', rt.user_id, - 'role', 'authenticated' - ), internal.access_token_jwt_secret()) into access_token - limit 1; - - if rt.multi_use = false then - rt_new_secret = gen_random_uuid(); - update refresh_tokens - set - hash = crypt(rt_new_secret, gen_salt('bf')), - uses = (uses + 1), - updated_at = clock_timestamp() - where refresh_tokens.id = rt.id; - else - -- re-set the updated_at timer so the token's validity is refreshed - update refresh_tokens - set - uses = (uses + 1), - updated_at = clock_timestamp() - where refresh_tokens.id = rt.id; - end if; - - if rt_new_secret is null then - return json_build_object( - 'access_token', access_token - ); - else - return json_build_object( - 'access_token', access_token, - 'refresh_token', json_build_object( - 'id', rt.id, - 'secret', rt_new_secret - ) - ); - end if; -commit; -end -$$ language plpgsql volatile security definer; - -comment on function generate_access_token is ' -Given a refresh_token, generates a new access_token. -If the refresh_token is not multi-use, the token''s secret is rotated. -If the refresh_token is multi-use, we reset its validity period by updating its `updated_at` column -'; diff --git a/supabase/migrations/18_billing.sql b/supabase/migrations/18_billing.sql deleted file mode 100644 index 8ae0f33efe..0000000000 --- a/supabase/migrations/18_billing.sql +++ /dev/null @@ -1,100 +0,0 @@ - -create function billing_report(billed_prefix catalog_prefix, billed_month timestamptz) -returns jsonb as $$ -declare - included_tasks bigint = 2; - task_rate bigint = 2000; - included_gb numeric = 10.0; - gb_rate bigint = 75; - - actual_gb numeric; - actual_tasks integer; - max_tasks_hour timestamptz; - - line_items jsonb = '[]'; - line_item_count numeric; - line_item_rate bigint; - subtotal bigint = 0; -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 - -- errcode 28000 causes potgrest 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; - - -- Ensure `billed_month` is the truncated start of the billed month. - billed_month = date_trunc('month', billed_month); - - -- Determine the total amount of data transfer done by tasks - -- under `billed_prefix` in the given `billed_month`. - select into actual_gb sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024) - from catalog_stats - where catalog_name ^@ billed_prefix - and grain = 'monthly' - and ts = billed_month - ; - - -- Determine the hour of the month that had the largest number of distinct running tasks. - -- Select out that hour, and the number of tasks. - select into max_tasks_hour, actual_tasks - ts, count(*) - from catalog_stats - where catalog_name ^@ billed_prefix - and grain = 'hourly' - and ts >= billed_month and ts < (billed_month + interval '1 month') - -- TODO(johnny): This should be based on logs != 0 instead. - and (bytes_written_by_me != 0 or bytes_read_by_me != 0) - group by ts - order by count(*) desc, ts desc - limit 1 - ; - - select into line_items jsonb_agg(jsonb_build_object( - 'description', "description", - 'count', round(count, 4), - 'rate', rate, - 'subtotal', round(count * rate) - )) from (values - ( - format('Included task shards (up to %s)', included_tasks), - least(included_tasks, actual_tasks), - 0 - ), - ( - format('Additional task shards minimum (assessed at %s)', max_tasks_hour), - greatest(0, actual_tasks - included_tasks), - task_rate - ), - ( - format('Included data processing (in GB, up to %sGB)', included_gb), - least(included_gb, actual_gb), - 0 - ), - ( - 'Additional data processing (in GB)', - greatest(0, actual_gb - included_gb), - gb_rate - ) - ) as t("description", count, rate); - - line_items = line_items || jsonb_build_object( - 'description', 'Subtotal is greater of task shards minimum, or data processing volume' - ); - subtotal = greatest((line_items->1->'subtotal')::bigint, (line_items->3->'subtotal')::bigint); - - return jsonb_build_object( - 'billed_prefix', billed_prefix, - 'billed_month', billed_month, - 'total_processed_data_gb', greatest(0, actual_gb), - 'max_concurrent_tasks', greatest(0, actual_tasks), - 'max_concurrent_tasks_at', max_tasks_hour, - 'line_items', line_items, - 'subtotal', subtotal - ); - -end -$$ language plpgsql volatile security definer; diff --git a/supabase/migrations/19_evolutions.sql b/supabase/migrations/19_evolutions.sql deleted file mode 100644 index 109ad98b8b..0000000000 --- a/supabase/migrations/19_evolutions.sql +++ /dev/null @@ -1,55 +0,0 @@ - --- evolutions are operations that update a draft to re-create one or more existing --- collections with a new name, and updates existing usages of the old collection --- to the new ones. -create table evolutions ( - like internal._model_async including all, - - user_id uuid references auth.users(id) not null default auth.uid(), - draft_id flowid not null, - collections json not null check (json_typeof(collections) = 'array'), - auto_publish boolean not null default false -); - -comment on table evolutions is - 'Evolutions are async jobs that rename a set of collections in a given draft, ' - 'and update and to the draft any captures and materializations of the old collection'; -comment on column evolutions.user_id is - 'Id of the user who created the job'; -comment on column evolutions.draft_id is - 'Id of the draft to operate on'; -comment on column evolutions.collections is - 'JSON array containing objects in the form of ' - '{"old_name": "acmeCo/foo", "new_name": "acmeCo/foo_v2"}.' - 'Note that the old_name of each collection must identify a draft_spec of the ' - 'given draft_id'; -comment on column evolutions.auto_publish is - 'whether to automatically publish the results of the evolution, if successful'; - -alter table evolutions enable row level security; - -create trigger "Notify agent about changes to evolution" after insert or update on evolutions -for each statement execute procedure internal.notify_agent(); - --- We don't impose a foreign key on drafts, because an evolution --- operation audit log may stick around much longer than the draft does. -create policy "Users can access only their initiated evolution operations" - on evolutions as permissive for select - using (user_id = auth.uid()); -create policy "Users can insert evolutions from permitted drafts" - on evolutions as permissive for insert - with check (draft_id in (select id from drafts)); - -grant select on evolutions to authenticated; -grant insert (draft_id, collections, detail) on evolutions to authenticated; - -comment on table evolutions is - 'evolutions are operations which test and publish drafts into live specifications'; -comment on column evolutions.user_id is - 'User who created the evolution'; -comment on column evolutions.draft_id is - 'Draft that is updated to affect the re-creation of the collections'; -comment on column evolutions.collections is - 'The names of the collections to re-create'; - - diff --git a/supabase/migrations/20241012000000_compacted.sql b/supabase/migrations/20241012000000_compacted.sql new file mode 100644 index 0000000000..45e57b7c82 --- /dev/null +++ b/supabase/migrations/20241012000000_compacted.sql @@ -0,0 +1,8282 @@ +-- +-- PostgreSQL database dump +-- + +-- Dumped from database version 15.1 (Ubuntu 15.1-1.pgdg20.04+1) +-- Dumped by pg_dump version 16.4 (Ubuntu 16.4-0ubuntu0.24.04.1) + +SET statement_timeout = 0; +SET lock_timeout = 0; +SET idle_in_transaction_session_timeout = 0; +SET client_encoding = 'UTF8'; +SET standard_conforming_strings = on; +SELECT pg_catalog.set_config('search_path', '', false); +SET check_function_bodies = false; +SET xmloption = content; +SET client_min_messages = warning; +SET row_security = off; + +-- +-- Name: internal; Type: SCHEMA; Schema: -; Owner: postgres +-- + +CREATE SCHEMA internal; + + +ALTER SCHEMA internal OWNER TO postgres; + +-- +-- Name: SCHEMA internal; Type: COMMENT; Schema: -; Owner: postgres +-- + +COMMENT ON SCHEMA internal IS 'Internal schema used for types, tables, and procedures we don''t expose in our API'; + + +-- +-- Name: public; Type: SCHEMA; Schema: -; Owner: postgres +-- + + + +ALTER SCHEMA public OWNER TO postgres; + +-- +-- Name: alert_type; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.alert_type AS ENUM ( + 'free_trial', + 'free_trial_ending', + 'free_trial_stalled', + 'missing_payment_method', + 'data_movement_stalled', + 'data_not_processed_in_interval' +); + + +ALTER TYPE public.alert_type OWNER TO postgres; + +-- +-- Name: catalog_name; Type: DOMAIN; Schema: public; Owner: postgres +-- + +CREATE DOMAIN public.catalog_name AS text + CONSTRAINT "Must be a valid catalog name" CHECK (((VALUE ~ '^([[:alpha:][:digit:]\-_.]+/)+[[:alpha:][:digit:]\-_.]+$'::text) AND ((VALUE) IS NFKC NORMALIZED))); + + +ALTER DOMAIN public.catalog_name OWNER TO postgres; + +-- +-- Name: DOMAIN catalog_name; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON DOMAIN public.catalog_name IS ' +catalog_name is a name within the Flow catalog namespace. + +Catalog names consist of Unicode-normalized (NFKC) letters, numbers, +"-", "_", and ".", with components separated by "/" and not ending in "/". + +For example: "acmeCo/anvils" or "acmeCo/products/TnT_v4", +but not "acmeCo//anvils/" or "acmeCo/some anvils". +'; + + +-- +-- Name: alert_snapshot; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.alert_snapshot AS ( + alert_type public.alert_type, + catalog_name public.catalog_name, + arguments json, + firing boolean +); + + +ALTER TYPE public.alert_snapshot OWNER TO postgres; + +-- +-- Name: catalog_prefix; Type: DOMAIN; Schema: public; Owner: postgres +-- + +CREATE DOMAIN public.catalog_prefix AS text + CONSTRAINT "Must be a valid catalog prefix" CHECK (((VALUE ~ '^([[:alpha:][:digit:]\-_.]+/)+$'::text) AND ((VALUE) IS NFKC NORMALIZED))); + + +ALTER DOMAIN public.catalog_prefix OWNER TO postgres; + +-- +-- Name: DOMAIN catalog_prefix; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON DOMAIN public.catalog_prefix IS ' +catalog_name is a prefix within the Flow catalog namespace. + +Catalog prefixes consist of Unicode-normalized (NFKC) letters, numbers, +"-", "_", and ".", with components separated by "/" and ending in a final "/". + +For example: "acmeCo/anvils/" or "acmeCo/products/TnT_v4/", +but not "acmeCo/anvils" or "acmeCo/some anvils". +'; + + +-- +-- Name: catalog_spec_type; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.catalog_spec_type AS ENUM ( + 'capture', + 'collection', + 'materialization', + 'test' +); + + +ALTER TYPE public.catalog_spec_type OWNER TO postgres; + +-- +-- Name: TYPE catalog_spec_type; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TYPE public.catalog_spec_type IS ' +Enumeration of Flow catalog specification types: +"capture", "collection", "materialization", or "test" +'; + + +-- +-- Name: catalog_tenant; Type: DOMAIN; Schema: public; Owner: postgres +-- + +CREATE DOMAIN public.catalog_tenant AS text + CONSTRAINT "Must be a valid catalog tenant" CHECK (((VALUE ~ '^[[:alpha:][:digit:]\-_.]+/$'::text) AND ((VALUE) IS NFKC NORMALIZED))); + + +ALTER DOMAIN public.catalog_tenant OWNER TO postgres; + +-- +-- Name: DOMAIN catalog_tenant; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON DOMAIN public.catalog_tenant IS ' +catalog_tenant is a prefix within the Flow catalog namespace +having exactly one top-level path component. + +Catalog tenants consist of Unicode-normalized (NFKC) letters, numbers, +"-", "_", and "." and ending in a final "/". + +For example: "acmeCo/" or "acmeCo.anvils/" or "acmeCo-TNT/", +but not "acmeCo" or "acmeCo/anvils/" or "acmeCo/TNT". +'; + + +-- +-- Name: id_generator(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.id_generator() RETURNS macaddr8 + LANGUAGE plpgsql SECURITY DEFINER + AS $$ + declare + -- This procedure generates unique 64-bit integers + -- with the following bit layout: + -- + -- 0b00000010100000101011010111111000100000101010100100011111100011100 + -- |-- Timestamp Millis --||-- SeqNo --||- Shard-| + -- + -- Estuary epoch is the first representable timestamp in generated IDs. + -- This could be zero, but subtracting |estuary_epoch| results in the + -- high bit being zero for the next ~34 years, + -- making ID representations equivalent for both signed and + -- unsigned 64-bit integers. + estuary_epoch bigint := 1600000000; + -- The id of this parallizable ID generation shard. + -- ID's generated inside of PostgreSQL always use |shard_id| zero. + -- We reserve other shard IDs for future parallized ID generation. + -- The allowed range is [0, 1024) (10 bits). + shard_id int := 0; + -- Sequence number is a monotonic tie-breaker for IDs generated + -- within the same millisecond. + -- The allowed range is [0, 8192) (13 bits). + seq_no bigint; + -- Current timestamp, as Unix millis since |estuary_epoch|. + now_millis bigint; + begin + -- We have 13 low bits of sequence ID, which allow us to generate + -- up to 8,192 unique IDs within each given millisecond. + select nextval('internal.shard_0_id_sequence') % 8192 into seq_no; + + select floor((extract(epoch from clock_timestamp()) - estuary_epoch) * 1000) into now_millis; + return lpad(to_hex((now_millis << 23) | (seq_no << 10) | (shard_id)), 16, '0')::macaddr8; + end; + $$; + + +ALTER FUNCTION internal.id_generator() OWNER TO postgres; + +-- +-- Name: FUNCTION id_generator(); Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON FUNCTION internal.id_generator() IS ' + id_generator produces 64bit unique, non-sequential identifiers. They: + * Have fixed storage that''s 1/2 the size of a UUID. + * Have a monotonic generation order. + * Embed a wall-clock timestamp than can be extracted if needed. + * Avoid the leaky-ness of SERIAL id''s. + + Adapted from: https://rob.conery.io/2014/05/29/a-better-id-generator-for-postgresql/ + Which itself was inspired by http://instagram-engineering.tumblr.com/post/10853187575/sharding-ids-at-instagram + '; + + +-- +-- Name: flowid; Type: DOMAIN; Schema: public; Owner: postgres +-- + +CREATE DOMAIN public.flowid AS macaddr8 DEFAULT internal.id_generator(); + + +ALTER DOMAIN public.flowid OWNER TO postgres; + +-- +-- Name: DOMAIN flowid; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON DOMAIN public.flowid IS ' +flowid is a montonic, time-ordered ID with gaps that fits within 64 bits. +We use macaddr8 as its underlying storage type because: + + 1) It''s stored as exactly 8 bytes, with the same efficiency as BIGINT. + 2) It has a flexible, convienient to_json() behavior that (crucially) + is loss-less by default when parsed in JavaScript. + +Postgres''s to_json() serializes BIGINT as a bare integer, +which is subject to silent rounding by many parsers when values +exceed 53 bits (as is common with flowid). + +The canonical flowid encoding is lower-case hexidecimal with each byte +separated by ":", which is what''s returned by Postgres & PostgREST. +Postgres (and PostgREST!) will accept any hex value of the correct +implied length, with bytes optionally separated by any arrangement +of ":" or "-". +'; + + +-- +-- Name: json_obj; Type: DOMAIN; Schema: public; Owner: postgres +-- + +CREATE DOMAIN public.json_obj AS json + CONSTRAINT json_obj_check CHECK ((json_typeof(VALUE) = 'object'::text)); + + +ALTER DOMAIN public.json_obj OWNER TO postgres; + +-- +-- Name: DOMAIN json_obj; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON DOMAIN public.json_obj IS 'json_obj is JSON which is restricted to the "object" type'; + + +-- +-- Name: jsonb_obj; Type: DOMAIN; Schema: public; Owner: postgres +-- + +CREATE DOMAIN public.jsonb_obj AS jsonb + CONSTRAINT jsonb_obj_check CHECK ((jsonb_typeof(VALUE) = 'object'::text)); + + +ALTER DOMAIN public.jsonb_obj OWNER TO postgres; + +-- +-- Name: DOMAIN jsonb_obj; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON DOMAIN public.jsonb_obj IS 'jsonb_obj is JSONB which is restricted to the "object" type'; + + +SET default_tablespace = ''; + +SET default_table_access_method = heap; + +-- +-- Name: applied_directives; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.applied_directives ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + job_status public.jsonb_obj DEFAULT '{"type": "queued"}'::jsonb NOT NULL, + logs_token uuid DEFAULT gen_random_uuid() NOT NULL, + directive_id public.flowid NOT NULL, + user_id uuid DEFAULT auth.uid() NOT NULL, + user_claims public.json_obj, + background boolean DEFAULT false NOT NULL +); + + +ALTER TABLE public.applied_directives OWNER TO postgres; + +-- +-- Name: TABLE applied_directives; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.applied_directives IS ' +Directives which are being or have been applied by the user. + +Users begin to apply a directive by exchanging its bearer token, which creates +a new applied_directives row. Then, upon supplying user_claims which further +parameterize the operation, the directive is validated and applied with the +user''s claims. +'; + + +-- +-- Name: COLUMN applied_directives.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN applied_directives.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN applied_directives.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.id IS 'ID of the record'; + + +-- +-- Name: COLUMN applied_directives.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN applied_directives.job_status; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.job_status IS 'Server-side job executation status of the record'; + + +-- +-- Name: COLUMN applied_directives.logs_token; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.logs_token IS 'Bearer token for accessing logs of the server-side operation'; + + +-- +-- Name: COLUMN applied_directives.directive_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.directive_id IS 'Directive which is being applied'; + + +-- +-- Name: COLUMN applied_directives.user_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.user_id IS 'User on whose behalf the directive is being applied'; + + +-- +-- Name: COLUMN applied_directives.user_claims; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.user_claims IS ' +User-supplied claims which parameterize the directive''s evaluation. + +User claims are initially null when an applied directive is first created, +and must be updated by the user for evaluation of the directive to begin. +'; + + +-- +-- Name: COLUMN applied_directives.background; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.applied_directives.background IS 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; + + +-- +-- Name: directives; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.directives ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + catalog_prefix public.catalog_prefix NOT NULL, + spec public.jsonb_obj NOT NULL, + token uuid DEFAULT gen_random_uuid(), + uses_remaining bigint, + CONSTRAINT "spec must have a string property `type`" CHECK ((NOT (jsonb_typeof(((spec)::jsonb -> 'type'::text)) IS DISTINCT FROM 'string'::text))) +); + + +ALTER TABLE public.directives OWNER TO postgres; + +-- +-- Name: TABLE directives; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.directives IS ' +Directives are scoped operations that users may elect to apply. +For example, a directive might grant access to a specific catalog namespace, +or provision the setup of a new organization. + +In general these operations require administrative priviledge that the user +does not directly have. The directive mechanism thus enables a user to have a +priviledged operation be applied on their behalf in a self-service fashion. + +The types of operations supported by directives are open ended, +but each generally has a well-defined (but parameterizable) scope, +and may also be subject to additional server-side verification checks. + +To apply a given directive a user must know its current token, which is +a secret credential that''s typically exchanged through another channel +(such as Slack, or email). The user then creates a corresponding entry in +applied_directives with accompanying user claims. +'; + + +-- +-- Name: COLUMN directives.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.directives.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN directives.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.directives.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN directives.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.directives.id IS 'ID of the record'; + + +-- +-- Name: COLUMN directives.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.directives.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN directives.catalog_prefix; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.directives.catalog_prefix IS ' +Catalog prefix which contains the directive. + +Operations undertaken by a directive are scoped within the catalog prefix, +and a user must admin the named prefix in order to admin its directives. +'; + + +-- +-- Name: COLUMN directives.spec; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.directives.spec IS ' +Specification of the directive. + +Specification documents must have a string `type` property which defines +the directive type. This type defines the meaning of the remainder of the +specification document. +'; + + +-- +-- Name: COLUMN directives.token; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.directives.token IS ' +Bearer token which is presented by a user to access and apply a directive. +'; + + +-- +-- Name: COLUMN directives.uses_remaining; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.directives.uses_remaining IS ' +The maximum number of times that this directive may be applied. +This value gets decremented each time the directive is applied. +Once it reaches 0, future attempts to apply the directive will fail. +A null here means that there is no limit. +'; + + +-- +-- Name: exchanged_directive; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.exchanged_directive AS ( + directive public.directives, + applied_directive public.applied_directives +); + + +ALTER TYPE public.exchanged_directive OWNER TO postgres; + +-- +-- Name: flow_type; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.flow_type AS ENUM ( + 'capture', + 'collection', + 'materialization', + 'test', + 'source_capture' +); + + +ALTER TYPE public.flow_type OWNER TO postgres; + +-- +-- Name: TYPE flow_type; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TYPE public.flow_type IS 'Represents the type of a dependency of one spec on another. This enum is a + strict superset of catalog_spec_type, for historical reasons.'; + + +-- +-- Name: grant_capability; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.grant_capability AS ENUM ( + 'x_00', + 'x_01', + 'x_02', + 'x_03', + 'x_04', + 'x_05', + 'x_06', + 'x_07', + 'x_08', + 'x_09', + 'read', + 'x_11', + 'x_12', + 'x_13', + 'x_14', + 'x_15', + 'x_16', + 'x_17', + 'x_18', + 'x_19', + 'write', + 'x_21', + 'x_22', + 'x_23', + 'x_24', + 'x_25', + 'x_26', + 'x_27', + 'x_28', + 'x_29', + 'admin' +); + + +ALTER TYPE public.grant_capability OWNER TO postgres; + +-- +-- Name: TYPE grant_capability; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TYPE public.grant_capability IS ' +grant_capability is an ordered enumeration of grant capabilities +bestowed upon a grantee by a grantor. Higher enumerated values +imply all of the capabilities of lower enum values. + +Enum values beginning with "x_" are placeholders for possible +future extension of the set of granted capabilities. + +A "read" capability allows a user or catalog specifications to +read from collections. + +A "write" capability allows a user or catalog specification to +write data into collections. + +The "admin" capability allows for creating, updating, and deleting +specifications. Unlike "read" or "write", this capability also recursively +grants the bearer all capabilities of the object_role. Put differently, +a user capable of changing a catalog specification is also granted the +capabilities which that specification itself uses to read and write data. +'; + + +-- +-- Name: json_pointer; Type: DOMAIN; Schema: public; Owner: postgres +-- + +CREATE DOMAIN public.json_pointer AS text + CONSTRAINT json_pointer_check CHECK (((VALUE = ''::text) OR ((VALUE ^@ '/'::text) AND (length(VALUE) > 1)))); + + +ALTER DOMAIN public.json_pointer OWNER TO postgres; + +-- +-- Name: jsonb_internationalized_value; Type: DOMAIN; Schema: public; Owner: postgres +-- + +CREATE DOMAIN public.jsonb_internationalized_value AS jsonb + CONSTRAINT jsonb_internationalized_value_check CHECK (((VALUE IS NULL) OR ((jsonb_typeof(VALUE) = 'object'::text) AND ((VALUE -> 'en-US'::text) IS NOT NULL)))); + + +ALTER DOMAIN public.jsonb_internationalized_value OWNER TO postgres; + +-- +-- Name: DOMAIN jsonb_internationalized_value; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON DOMAIN public.jsonb_internationalized_value IS 'jsonb_internationalized_value is JSONB object which is required to at least have en-US internationalized values'; + + +-- +-- Name: payment_provider_type; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.payment_provider_type AS ENUM ( + 'stripe', + 'external' +); + + +ALTER TYPE public.payment_provider_type OWNER TO postgres; + +-- +-- Name: TYPE payment_provider_type; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TYPE public.payment_provider_type IS ' +Enumeration of which payment provider this tenant is using. +'; + + +-- +-- Name: user_profile; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.user_profile AS ( + user_id uuid, + email text, + full_name text, + avatar_url text +); + + +ALTER TYPE public.user_profile OWNER TO postgres; + +-- +-- Name: access_token_jwt_secret(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.access_token_jwt_secret() RETURNS text + LANGUAGE sql STABLE + AS $$ + + select coalesce(current_setting('app.settings.jwt_secret', true), 'super-secret-jwt-token-with-at-least-32-characters-long') limit 1 + +$$; + + +ALTER FUNCTION internal.access_token_jwt_secret() OWNER TO postgres; + +-- +-- Name: billing_report_202308(public.catalog_prefix, timestamp with time zone); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.billing_report_202308(billed_prefix public.catalog_prefix, billed_month timestamp with time zone) RETURNS jsonb + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +declare + -- Output variables. + o_daily_usage jsonb; + o_data_gb numeric; + o_line_items jsonb = '[]'; + o_recurring_fee integer; + o_subtotal integer; + o_task_hours numeric; + o_trial_credit integer; + o_free_tier_credit integer; + o_trial_start date; + o_trial_range daterange; + o_free_tier_range daterange; + o_billed_range daterange; +begin + + -- Ensure `billed_month` is the truncated start of the billed month. + billed_month = date_trunc('month', billed_month); + + with vars as ( + select + t.data_tiers, + t.trial_start, + t.usage_tiers, + tstzrange(billed_month, billed_month + '1 month', '[)') as billed_range, + case when t.trial_start is not null + then daterange(t.trial_start::date, ((t.trial_start::date) + interval '1 month')::date, '[)') + else 'empty' end as trial_range, + -- In order to smoothly transition between free tier credit and free trial credit, + -- the free tier covers all usage up to, but _not including_ the trial start date. + -- On the trial start date, the free trial credit takes over. + daterange(NULL, t.trial_start::date, '[)') as free_tier_range, + -- Reveal contract costs only when computing whole-tenant billing. + case when t.tenant = billed_prefix then t.recurring_usd_cents else 0 end as recurring_fee + from tenants t + where billed_prefix ^@ t.tenant -- Prefix starts with tenant. + ), + -- Roll up each day's incremental usage. + daily_stat_deltas as ( + select + ts, + sum(bytes_written_by_me + bytes_read_by_me) / (10.0^9.0) as data_gb, + sum(usage_seconds) / (60.0 * 60) as task_hours + from catalog_stats, vars + where catalog_name ^@ billed_prefix -- Name starts with prefix. + and grain = 'daily' + and billed_range @> ts + group by ts + ), + -- Map to cumulative daily usage. + -- Note sum(...) over (order by ts) yields the running sum of its aggregate. + daily_stats as ( + select + ts, + sum(data_gb) over w as data_gb, + sum(task_hours) over w as task_hours + from daily_stat_deltas + window w as (order by ts) + ), + -- Extend with line items for each category for the period ending with the given day. + daily_line_items as ( + select + daily_stats.*, + internal.tier_line_items(ceil(data_gb)::integer, data_tiers, 'Data processing', 'GB') as data_line_items, + internal.tier_line_items(ceil(task_hours)::integer, usage_tiers, 'Task usage', 'hour') as task_line_items + from daily_stats, vars + ), + -- Extend with per-category subtotals for the period ending with the given day. + daily_totals as ( + select + daily_line_items.*, + data_subtotal, + task_subtotal + from daily_line_items, + lateral (select sum((li->>'subtotal')::numeric) as data_subtotal from jsonb_array_elements(data_line_items) li) l1, + lateral (select sum((li->>'subtotal')::numeric) as task_subtotal from jsonb_array_elements(task_line_items) li) l2 + ), + -- Map cumulative totals to per-day deltas. + daily_deltas as ( + select + ts, + data_gb - (coalesce(lag(data_gb, 1) over w, 0)) as data_gb, + data_subtotal - (coalesce(lag(data_subtotal, 1) over w, 0)) as data_subtotal, + task_hours - (coalesce(lag(task_hours, 1) over w, 0)) as task_hours, + task_subtotal - (coalesce(lag(task_subtotal, 1) over w, 0)) as task_subtotal + from daily_totals + window w as (order by ts) + ), + -- 1) Group daily_deltas into a JSON array + -- 2) Sum a trial credit from daily deltas that overlap with the trial period. + daily_array_and_trial_credits as ( + select + jsonb_agg(jsonb_build_object( + 'ts', ts, + 'data_gb', data_gb, + 'data_subtotal', data_subtotal, + 'task_hours', task_hours, + 'task_subtotal', task_subtotal + )) as daily_usage, + coalesce(sum(data_subtotal + task_subtotal) filter (where trial_range @> (ts::date)),0 ) as trial_credit, + coalesce(sum(data_subtotal + task_subtotal) filter (where free_tier_range @> (ts::date)),0 ) as free_tier_credit + from daily_deltas, vars + ), + -- The last day captures the cumulative billed period. + last_day as ( + select * from daily_line_items + order by ts desc limit 1 + ), + -- If we're reporting for the whole tenant then gather billing adjustment line-items. + adjustments as ( + select coalesce(jsonb_agg( + jsonb_build_object( + 'description', detail, + 'count', 1, + 'rate', usd_cents, + 'subtotal', usd_cents + ) + ), '[]') as adjustment_line_items + from internal.billing_adjustments a + where a.tenant = billed_prefix and a.billed_month = billing_report_202308.billed_month + ) + select into + -- Block of variables being selected into. + o_daily_usage, + o_data_gb, + o_line_items, + o_recurring_fee, + o_task_hours, + o_trial_credit, + o_trial_start, + o_trial_range, + o_billed_range, + o_free_tier_credit, + o_free_tier_range + -- The actual selected columns. + daily_usage, + data_gb, + data_line_items || task_line_items || adjustment_line_items, + recurring_fee, + task_hours, + trial_credit, + trial_start, + trial_range, + billed_range, + free_tier_credit, + free_tier_range + from daily_array_and_trial_credits, last_day, adjustments, vars; + + -- Add line items for recurring service fee & free trial credit. + if o_recurring_fee != 0 then + o_line_items = jsonb_build_object( + 'description', 'Recurring service charge', + 'count', 1, + 'rate', o_recurring_fee, + 'subtotal', o_recurring_fee + ) || o_line_items; + end if; + + -- Display a (possibly zero) free trial credit if the trial range overlaps the billed range + if o_trial_range && o_billed_range then + o_line_items = o_line_items || jsonb_build_object( + 'description', format('Free trial credit (%s - %s)', lower(o_trial_range), (upper(o_trial_range) - interval '1 day')::date), + 'count', 1, + 'rate', -o_trial_credit, + 'subtotal', -o_trial_credit + ); + end if; + + -- Display the free tier credit if the free tier range overlaps the billed range + if o_free_tier_range && o_billed_range then + o_line_items = o_line_items || jsonb_build_object( + 'description', case when upper(o_free_tier_range) is not null + then format('Free tier credit ending %s', (upper(o_free_tier_range) - interval '1 day')::date) + else 'Free tier credit' + end, + 'count', 1, + 'rate', -o_free_tier_credit, + 'subtotal', -o_free_tier_credit + ); + end if; + + -- Roll up the final subtotal. + select into o_subtotal sum((l->>'subtotal')::numeric) + from jsonb_array_elements(o_line_items) l; + + return jsonb_build_object( + 'billed_month', billed_month, + 'billed_prefix', billed_prefix, + 'daily_usage', o_daily_usage, + 'line_items', o_line_items, + 'processed_data_gb', o_data_gb, + 'recurring_fee', o_recurring_fee, + 'subtotal', o_subtotal, + 'task_usage_hours', o_task_hours, + 'trial_credit', coalesce(o_trial_credit, 0), + 'free_tier_credit', coalesce(o_free_tier_credit, 0), + 'trial_start', o_trial_start + ); + +end +$$; + + +ALTER FUNCTION internal.billing_report_202308(billed_prefix public.catalog_prefix, billed_month timestamp with time zone) OWNER TO postgres; + +-- +-- Name: compute_incremental_line_items(text, text, numeric, integer[], numeric); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.compute_incremental_line_items(item_name text, item_unit text, single_usage numeric, tiers integer[], running_usage_sum numeric) RETURNS jsonb + LANGUAGE plpgsql + AS $$ +declare + line_items jsonb = '[]'; + + -- Calculating tiered usage. + tier_rate integer; + tier_pivot integer; + tier_count numeric; +begin + -- Walk up the tiers + for tier_idx in 1..array_length(tiers,1) by 2 loop + tier_rate = tiers[tier_idx]; + tier_pivot = tiers[tier_idx+1]; + if tier_pivot is null then + -- No limits here, roll all of the remaining usage into this tier + tier_count = single_usage; + running_usage_sum = running_usage_sum + tier_count; + if tier_count > 0 then + line_items = line_items || jsonb_build_object( + 'description', format( + '%s (at %s/%s)', + item_name, + (tier_rate / 100.0)::money, + item_unit + ), + 'count', tier_count, + 'rate', tier_rate, + 'subtotal_frac', tier_count * tier_rate + ); + end if; + elsif tier_pivot > running_usage_sum then + -- We haven't already surpassed this tier's pivot + -- Calculate how much more usage we'd need to surpass this tier + tier_count = least(single_usage, tier_pivot - running_usage_sum); + single_usage = single_usage - tier_count; + running_usage_sum = running_usage_sum + tier_count; + if tier_count > 0 then + line_items = line_items || jsonb_build_object( + 'description', format( + case + when tier_idx = 1 then '%s (first %s%ss at %s/%s)' + else '%s (next %s%ss at %s/%s)' + end, + item_name, + tier_pivot, + item_unit, + (tier_rate / 100.0)::money, + item_unit + ), + 'count', tier_count, + 'rate', tier_rate, + 'subtotal_frac', tier_count * tier_rate + ); + end if; + end if; + end loop; + + return jsonb_build_object( + 'line_items', line_items, + 'running_usage_sum', running_usage_sum + ); +end +$$; + + +ALTER FUNCTION internal.compute_incremental_line_items(item_name text, item_unit text, single_usage numeric, tiers integer[], running_usage_sum numeric) OWNER TO postgres; + +-- +-- Name: create_auto_discovers(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.create_auto_discovers() RETURNS integer + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +declare + support_user_id uuid = (select id from auth.users where email = 'support@estuary.dev'); + next_row internal.next_auto_discovers; + total_created integer := 0; + tmp_draft_id flowid; + tmp_discover_id flowid; +begin + +for next_row in select * from internal.next_auto_discovers +loop + -- Create a draft, which we'll discover into + insert into drafts (user_id) values (support_user_id) returning id into tmp_draft_id; + + insert into discovers (capture_name, draft_id, connector_tag_id, endpoint_config, update_only, auto_publish, auto_evolve, background) + values ( + next_row.capture_name, + tmp_draft_id, + next_row.connector_tags_id, + next_row.endpoint_json, + not next_row.add_new_bindings, + true, + next_row.evolve_incompatible_collections, + true + ) returning id into tmp_discover_id; + + -- This is just useful when invoking the function manually. + total_created := total_created + 1; +end loop; + +return total_created; +end; +$$; + + +ALTER FUNCTION internal.create_auto_discovers() OWNER TO postgres; + +-- +-- Name: FUNCTION create_auto_discovers(); Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON FUNCTION internal.create_auto_discovers() IS 'Creates discovers jobs for each capture that is due for an automatic discover. Each disocver will have auto_publish +set to true. The update_only and auto_evolve columns of the discover will be set based on the addNewBindings and +evolveIncompatibleCollections fields in the capture spec. This function is idempotent. Once a discover is created by +this function, the next_auto_discovers view will no longer include that capture until its interval has passed again. +So its safe to call this function at basically any frequency. The return value of the function is the count of newly +created discovers jobs.'; + + +-- +-- Name: delete_old_cron_runs(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.delete_old_cron_runs() RETURNS integer + LANGUAGE sql SECURITY DEFINER + AS $$ + with r as ( + delete from cron.job_run_details where end_time < now() - '10 days'::interval returning runid + ) + select count(*) from r; +$$; + + +ALTER FUNCTION internal.delete_old_cron_runs() OWNER TO postgres; + +-- +-- Name: FUNCTION delete_old_cron_runs(); Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON FUNCTION internal.delete_old_cron_runs() IS 'deletes cron.job_run_details rows that have aged out.'; + + +-- +-- Name: delete_old_drafts(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.delete_old_drafts() RETURNS integer + LANGUAGE sql SECURITY DEFINER + AS $$ + with d as ( + delete from public.drafts where updated_at < (now() - '10 days'::interval) returning id + ) + select count(id) from d; +$$; + + +ALTER FUNCTION internal.delete_old_drafts() OWNER TO postgres; + +-- +-- Name: FUNCTION delete_old_drafts(); Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON FUNCTION internal.delete_old_drafts() IS 'deletes drafts, discovers, draft_specs, and draft_errors rows that have aged out'; + + +-- +-- Name: delete_old_hourly_stats(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.delete_old_hourly_stats() RETURNS integer + LANGUAGE sql SECURITY DEFINER + AS $$ + with s as ( + delete from catalog_stats_hourly where grain = 'hourly' and ts < (now() - '30 days'::interval) returning ts + ) + select count(ts) from s; +$$; + + +ALTER FUNCTION internal.delete_old_hourly_stats() OWNER TO postgres; + +-- +-- Name: FUNCTION delete_old_hourly_stats(); Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON FUNCTION internal.delete_old_hourly_stats() IS 'deletes catalog_stats_hourly rows that have aged out'; + + +-- +-- Name: delete_old_log_lines(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.delete_old_log_lines() RETURNS integer + LANGUAGE sql SECURITY DEFINER + AS $$ + with l as ( + delete from internal.log_lines where logged_at < (now() - '2 days'::interval) returning logged_at + ) + select count(*) from l; +$$; + + +ALTER FUNCTION internal.delete_old_log_lines() OWNER TO postgres; + +-- +-- Name: FUNCTION delete_old_log_lines(); Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON FUNCTION internal.delete_old_log_lines() IS 'deletes internal.log_lines rows that have aged out'; + + +-- +-- Name: evaluate_alert_events(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.evaluate_alert_events() RETURNS void + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +begin + + -- Create alerts which have transitioned from !firing => firing + with open_alerts as ( + select alert_type, catalog_name from alert_history + where resolved_at is null + ) + insert into alert_history (alert_type, catalog_name, fired_at, arguments) + select alert_all.alert_type, alert_all.catalog_name, now(), alert_all.arguments + from alert_all + left join open_alerts on + alert_all.alert_type = open_alerts.alert_type and + alert_all.catalog_name = open_alerts.catalog_name + where alert_all.firing and open_alerts is null; + + -- Resolve alerts that have transitioned from firing => !firing + with open_alerts as ( + select + alert_history.alert_type, + alert_history.catalog_name, + fired_at + from alert_history + where resolved_at is null + ), + -- Find all open_alerts for which either there is not a row in alerts_all, + -- or there is but its firing field is false. + closing_alerts as ( + select + open_alerts.alert_type, + open_alerts.catalog_name, + fired_at, + coalesce(alert_all.arguments, null) as arguments + from open_alerts + left join alert_all on + alert_all.alert_type = open_alerts.alert_type and + alert_all.catalog_name = open_alerts.catalog_name + where + -- The open alert is no longer in alert_all, therefore it's no longer firing + alert_all.alert_type is null or + -- The open is still tracked, but it has stopped firing + not alert_all.firing + ) + update alert_history + set resolved_at = now(), + resolved_arguments = closing_alerts.arguments + from closing_alerts + where alert_history.alert_type = closing_alerts.alert_type + and alert_history.catalog_name = closing_alerts.catalog_name + and alert_history.fired_at = closing_alerts.fired_at; + +end; +$$; + + +ALTER FUNCTION internal.evaluate_alert_events() OWNER TO postgres; + +-- +-- Name: freeze_billing_month(timestamp with time zone); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.freeze_billing_month(billed_month timestamp with time zone) RETURNS integer + LANGUAGE plpgsql + AS $$ +declare + tenant_row record; + tenant_count integer = 0; +begin + for tenant_row in select tenant as tenant_name from tenants loop + insert into internal.billing_historicals + select + report->>'billed_prefix' as tenant, + (report->>'billed_month')::timestamptz as billed_month, + report + from internal.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 +$$; + + +ALTER FUNCTION internal.freeze_billing_month(billed_month timestamp with time zone) OWNER TO postgres; + +-- +-- Name: gateway_endpoint_url(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.gateway_endpoint_url() RETURNS text + LANGUAGE sql STABLE SECURITY DEFINER + AS $$ + + select url + from internal.gateway_endpoints + limit 1 + +$$; + + +ALTER FUNCTION internal.gateway_endpoint_url() OWNER TO postgres; + +-- +-- Name: incremental_usage_report(text, public.catalog_prefix, tstzrange); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.incremental_usage_report(requested_grain text, billed_prefix public.catalog_prefix, billed_range tstzrange) RETURNS jsonb + LANGUAGE plpgsql + AS $$ +declare + -- Retrieved from tenants table. + data_tiers integer[]; + usage_tiers integer[]; + + granules jsonb = '[]'; + returned_data_line_items jsonb = '{}'; + returned_hours_line_items jsonb = '{}'; + combined_line_items jsonb; + + subtotal_frac numeric; + + running_gb_sum numeric = 0; + running_hour_sum numeric = 0; + line_items jsonb = '[]'; +begin + -- 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; + + -- Get all stats records for the selected time period at the selected granularity + select into granules + (select json_agg(res.obj) from ( + select jsonb_build_object( + 'processed_data_gb', sum((bytes_written_by_me + bytes_read_by_me)) / (1024.0 * 1024 * 1024), + 'task_usage_hours', sum(usage_seconds) / (60.0 * 60), + 'ts', ts + ) as obj + from catalog_stats + where catalog_name ^@ billed_prefix + and grain = requested_grain + and billed_range @> ts + group by ts + ) as res) + ; + + for idx in 0..jsonb_array_length(granules)-1 loop + returned_data_line_items = internal.compute_incremental_line_items('Data processing', 'GB', (granules->idx->'processed_data_gb')::numeric, data_tiers, running_gb_sum); + running_gb_sum = (returned_data_line_items->'running_usage_sum')::numeric; + + returned_hours_line_items = internal.compute_incremental_line_items('Task usage', 'hour', (granules->idx->'task_usage_hours')::numeric, usage_tiers, running_hour_sum); + running_hour_sum = (returned_hours_line_items->'running_usage_sum')::numeric; + + combined_line_items = (returned_data_line_items->'line_items')::jsonb || (returned_hours_line_items->'line_items')::jsonb; + + select into subtotal_frac sum((item->'subtotal_frac')::numeric) from jsonb_array_elements(combined_line_items) as item; + + line_items = line_items || jsonb_build_object( + 'line_items', combined_line_items, + 'subtotal_frac', subtotal_frac, + 'processed_data_gb', (granules->idx->'processed_data_gb')::numeric, + 'task_usage_hours', (granules->idx->'task_usage_hours')::numeric, + 'ts', granules->idx->'ts' + ); + end loop; + + return line_items; +end +$$; + + +ALTER FUNCTION internal.incremental_usage_report(requested_grain text, billed_prefix public.catalog_prefix, billed_range tstzrange) OWNER TO postgres; + +-- +-- Name: jsonb_merge_diff(jsonb, jsonb); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.jsonb_merge_diff(target jsonb, source jsonb) RETURNS jsonb + LANGUAGE plpgsql IMMUTABLE + AS $$ +begin + case + when "target" isnull then + return 'null'; -- Marker to remove location. + when jsonb_typeof("target") is distinct from 'object' or + jsonb_typeof("source") is distinct from 'object' then + return (case + when "target" = "source" then null + else jsonb_strip_nulls("target") + end); + else + return ( + with props as ( + select + coalesce("tkey", "skey") as "key", + internal.jsonb_merge_diff("tval", "sval") as "val" + from jsonb_each("target") e1("tkey", "tval") + full outer join jsonb_each("source") e2("skey", "sval") on "tkey" = "skey" + ) + -- If no props are different, the result is NULL (not 'null'). + select jsonb_object_agg("key", "val") + from props + where "val" is not null + ); + end case; +end; +$$; + + +ALTER FUNCTION internal.jsonb_merge_diff(target jsonb, source jsonb) OWNER TO postgres; + +-- +-- Name: jsonb_merge_patch(jsonb, jsonb); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.jsonb_merge_patch(target jsonb, patch jsonb) RETURNS jsonb + LANGUAGE plpgsql IMMUTABLE + AS $$ +begin + case + when "patch" is null then + return "target"; + when "patch" = 'null' then + return null; -- Remove location. + when jsonb_typeof("target") is distinct from 'object' or + jsonb_typeof("patch") is distinct from 'object' then + -- If either side is not an object, take the patch. + return jsonb_strip_nulls("patch"); + when "target" = jsonb_strip_nulls("patch") then + -- Both are objects, and the patch doesn't change the target. + -- This case *could* be handled by the recursive case, + -- but equality and stripping nulls is dirt cheap compared to + -- the cost of recursive jsonb_object_agg, which must repeatedly + -- copy nested sub-structure. + return "target"; + else + return ( + with props as ( + select + coalesce("tkey", "pkey") as "key", + case + when "pval" isnull then "tval" + else internal.jsonb_merge_patch("tval", "pval") + end as "val" + from jsonb_each("target") e1("tkey", "tval") + full outer join jsonb_each("patch") e2("pkey", "pval") on "tkey" = "pkey" + where "pval" is distinct from 'null' + ) + select coalesce(jsonb_object_agg("key", "val"), '{}') from props + ); + end case; +end; +$$; + + +ALTER FUNCTION internal.jsonb_merge_patch(target jsonb, patch jsonb) OWNER TO postgres; + +-- +-- Name: notify_agent(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.notify_agent() RETURNS trigger + LANGUAGE plpgsql + AS $$ +declare + payload text; +begin + -- Build the payload + payload := json_build_object('timestamp',CURRENT_TIMESTAMP,'table',TG_TABLE_NAME); + + -- Notify the channel + perform pg_notify('agent_notifications', payload); + + return null; +END; +$$; + + +ALTER FUNCTION internal.notify_agent() OWNER TO postgres; + +-- +-- Name: on_applied_directives_delete(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.on_applied_directives_delete() RETURNS trigger + LANGUAGE plpgsql + AS $$ +begin + if OLD.job_status->>'type' = 'success' then + raise 'Cannot delete an applied directive which has completed' + using errcode = 'check_violation'; + end if; + + return OLD; +end +$$; + + +ALTER FUNCTION internal.on_applied_directives_delete() OWNER TO postgres; + +-- +-- Name: on_applied_directives_update(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.on_applied_directives_update() RETURNS trigger + LANGUAGE plpgsql + AS $$ +begin + if OLD.job_status->>'type' = 'success' then + raise 'Cannot modify an applied directive which has completed' + using errcode = 'check_violation'; + end if; + + -- Clear a prior failed application, allowing the user to retry. + if OLD.user_claims::text is distinct from NEW.user_claims::text then + NEW.job_status = '{"type":"queued"}'; + end if; + + return NEW; +end +$$; + + +ALTER FUNCTION internal.on_applied_directives_update() OWNER TO postgres; + +-- +-- Name: on_inferred_schema_update(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.on_inferred_schema_update() RETURNS trigger + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +begin + +-- The least function is necessary in order to avoid delaying a controller job in scenarios +-- where there is a backlog of controller runs that are due. +update live_specs set controller_next_run = least(controller_next_run, now()) +where catalog_name = new.collection_name and spec_type = 'collection'; + +return null; +end; +$$; + + +ALTER FUNCTION internal.on_inferred_schema_update() OWNER TO postgres; + +-- +-- Name: FUNCTION on_inferred_schema_update(); Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON FUNCTION internal.on_inferred_schema_update() IS 'Schedules a run of the controller in response to an inferred_schemas change.'; + + +-- +-- Name: send_alerts(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.send_alerts() RETURNS trigger + LANGUAGE plpgsql + AS $$ +declare + token text; +begin + select decrypted_secret into token from vault.decrypted_secrets where name = 'alert-email-fn-shared-secret' limit 1; + perform + net.http_post( + -- 'http://host.docker.internal:5431/functions/v1/alerts', + 'https://eyrcnmuzzyriypdajwdk.supabase.co/functions/v1/alerts', + to_jsonb(new.*), + headers:=format('{"Content-Type": "application/json", "Authorization": "Basic %s"}', token)::jsonb, + timeout_milliseconds:=90000 + ); + return null; +end; +$$; + + +ALTER FUNCTION internal.send_alerts() OWNER TO postgres; + +-- +-- Name: set_new_free_trials(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.set_new_free_trials() RETURNS integer + LANGUAGE plpgsql + AS $$ +declare + tenant_row record; + update_count integer = 0; +begin + for tenant_row in select tenant from internal.new_free_trial_tenants loop + update tenants set trial_start = date_trunc('day', now()) + where tenants.tenant = tenant_row.tenant; + + -- INSERT statements set FOUND true if at least one row is affected, false if no row is affected. + if found then + update_count = update_count + 1; + end if; + end loop; + return update_count; +end +$$; + + +ALTER FUNCTION internal.set_new_free_trials() OWNER TO postgres; + +-- +-- Name: sign_jwt(json); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.sign_jwt(obj json) RETURNS text + LANGUAGE sql STABLE SECURITY DEFINER + AS $$ + + select sign(obj, secret_key::text) + from internal.gateway_auth_keys + limit 1 + +$$; + + +ALTER FUNCTION internal.sign_jwt(obj json) OWNER TO postgres; + +-- +-- Name: task_roles(text, public.grant_capability); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.task_roles(task_name_or_prefix text, min_capability public.grant_capability DEFAULT 'x_00'::public.grant_capability) RETURNS TABLE(role_prefix public.catalog_prefix, capability public.grant_capability) + LANGUAGE sql STABLE + AS $$ + + with recursive + all_roles(role_prefix, capability) as ( + select g.object_role, g.capability from role_grants g + where starts_with(task_name_or_prefix, g.subject_role) + and g.capability >= min_capability + union + -- Recursive case: for each object_role granted as 'admin', + -- project through grants where object_role acts as the subject_role. + select g.object_role, g.capability + from role_grants g, all_roles a + where starts_with(a.role_prefix, g.subject_role) + and g.capability >= min_capability + and a.capability = 'admin' + ) + select role_prefix, max(capability) from all_roles + group by role_prefix + order by role_prefix; + +$$; + + +ALTER FUNCTION internal.task_roles(task_name_or_prefix text, min_capability public.grant_capability) OWNER TO postgres; + +-- +-- Name: test_billing_report(public.catalog_prefix, timestamp with time zone); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.test_billing_report(billed_prefix public.catalog_prefix, billed_month timestamp with time zone) RETURNS jsonb + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +#variable_conflict use_variable +declare + -- Auth checks + has_admin_grant boolean; + has_bypassrls boolean; + + -- Computed + recurring_usd_cents integer; + free_trial_range tstzrange; + billed_range tstzrange; + free_trial_overlap tstzrange; + + free_trial_credit numeric; + + -- Temporary line items holders for free trial calculations + task_usage_line_items jsonb = '[]'; + data_usage_line_items jsonb = '[]'; + + -- Calculating adjustments. + adjustment internal.billing_adjustments; + + -- Aggregated outputs. + line_items jsonb = '[]'; + subtotal_usd_cents integer; + processed_data_gb numeric; + task_usage_hours numeric; + + -- Free trial outputs + free_trial_gb numeric; + free_trial_hours numeric; +begin + + -- Ensure `billed_month` is the truncated start of the billed month. + billed_month = date_trunc('month', billed_month); + billed_range = tstzrange(billed_month, billed_month + '1 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 free_trial_range + case + when t.free_trial_start is null then 'empty'::tstzrange + -- Inclusive start, exclusive end + else tstzrange(date_trunc('day', t.free_trial_start), date_trunc('day', t.free_trial_start) + '1 month', '[)') + end + 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 + ; + + -- 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; + + select into line_items, processed_data_gb, task_usage_hours + line_items || ( + select json_agg( + (item - 'subtotal_frac') || + jsonb_build_object( + 'subtotal', round((item->'subtotal_frac')::numeric) + ) + )::jsonb + from jsonb_array_elements(report->0->'line_items') as item + ), + (report->0->'processed_data_gb')::numeric, + (report->0->'task_usage_hours')::numeric + from internal.incremental_usage_report('monthly', billed_prefix, billed_range) as report; + + -- Does the free trial range overlap the month in question? + if not isempty(free_trial_range) and (free_trial_range && billed_range) then + free_trial_overlap = billed_range * free_trial_range; + -- Determine the total amount of data processing and task usage under `billed_prefix` + -- during the portion of `billed_month` that `free_trial_range` covers. + select into + free_trial_credit sum((line_item->>'subtotal_frac')::numeric) + from + jsonb_array_elements( + internal.incremental_usage_report('daily', billed_prefix, free_trial_overlap) + ) as line_item; + + line_items = line_items || jsonb_build_object( + 'description', 'Free trial credit', + 'count', 1, + 'rate', round(free_trial_credit) * -1, + 'subtotal', round(free_trial_credit) * -1 + ); + end if; + + -- 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 +$$; + + +ALTER FUNCTION internal.test_billing_report(billed_prefix public.catalog_prefix, billed_month timestamp with time zone) OWNER TO postgres; + +-- +-- Name: tier_line_items(integer, integer[], text, text); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.tier_line_items(amount integer, tiers integer[], name text, unit text) RETURNS jsonb + LANGUAGE plpgsql + AS $_$ +declare + o_line_items jsonb = '[]'; -- Output variable. + tier_count integer; + tier_pivot integer; + tier_rate integer; +begin + + for idx in 1..array_length(tiers, 1) by 2 loop + tier_rate = tiers[idx]; + tier_pivot = tiers[idx+1]; + tier_count = least(amount, tier_pivot); + amount = amount - tier_count; + + o_line_items = o_line_items || jsonb_build_object( + 'description', format( + case + when tier_pivot is null then '%1$s (at %4$s/%2$s)' -- Data processing (at $0.50/GB) + when idx = 1 then '%1s (first %3$s %2$ss at %4$s/%2$s)' -- Data processing (first 30 GBs at $0.50/GB) + else '%1$s (next %3$s %2$ss at %4$s/%2$s)' -- Data processing (next 6 GBs at $0.25/GB) + end, + name, + unit, + tier_pivot, + (tier_rate / 100.0)::money + ), + 'count', tier_count, + 'rate', tier_rate, + 'subtotal', tier_count * tier_rate + ); + end loop; + + return o_line_items; + +end +$_$; + + +ALTER FUNCTION internal.tier_line_items(amount integer, tiers integer[], name text, unit text) OWNER TO postgres; + +-- +-- Name: update_support_role(); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.update_support_role() RETURNS trigger + LANGUAGE plpgsql + AS $$ +begin + insert into role_grants ( + detail, + subject_role, + object_role, + capability + ) + select + 'Automagically grant support role access to new tenant', + 'estuary_support/', + tenants.tenant, + 'admin' + from tenants + left join role_grants on + role_grants.object_role = tenants.tenant and + role_grants.subject_role = 'estuary_support/' + where role_grants.id is null and + tenants.tenant not in ('ops/', 'estuary/'); + + return null; +END; +$$; + + +ALTER FUNCTION internal.update_support_role() OWNER TO postgres; + +-- +-- Name: user_roles(uuid, public.grant_capability); Type: FUNCTION; Schema: internal; Owner: postgres +-- + +CREATE FUNCTION internal.user_roles(target_user_id uuid, min_capability public.grant_capability DEFAULT 'x_00'::public.grant_capability) RETURNS TABLE(role_prefix public.catalog_prefix, capability public.grant_capability) + LANGUAGE sql STABLE + AS $$ + + with recursive + all_roles(role_prefix, capability) as ( + select object_role, capability from user_grants + where user_id = target_user_id + and capability >= min_capability + union + -- Recursive case: for each object_role granted as 'admin', + -- project through grants where object_role acts as the subject_role. + select role_grants.object_role, role_grants.capability + from role_grants, all_roles + where role_grants.subject_role ^@ all_roles.role_prefix + and role_grants.capability >= min_capability + and all_roles.capability = 'admin' + ) + select role_prefix, max(capability) from all_roles + group by role_prefix + order by role_prefix; + +$$; + + +ALTER FUNCTION internal.user_roles(target_user_id uuid, min_capability public.grant_capability) OWNER TO postgres; + +-- +-- Name: auth_roles(public.grant_capability); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.auth_roles(min_capability public.grant_capability DEFAULT 'x_00'::public.grant_capability) RETURNS TABLE(role_prefix public.catalog_prefix, capability public.grant_capability) + LANGUAGE sql STABLE SECURITY DEFINER + AS $$ + select role_prefix, capability from internal.user_roles(auth_uid(), min_capability) +$$; + + +ALTER FUNCTION public.auth_roles(min_capability public.grant_capability) OWNER TO postgres; + +-- +-- Name: FUNCTION auth_roles(min_capability public.grant_capability); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.auth_roles(min_capability public.grant_capability) IS 'auth_roles returns all roles and associated capabilities of the user'; + + +-- +-- Name: auth_uid(); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.auth_uid() RETURNS uuid + LANGUAGE sql STABLE + AS $$ + select auth.uid() +$$; + + +ALTER FUNCTION public.auth_uid() OWNER TO postgres; + +-- +-- Name: FUNCTION auth_uid(); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.auth_uid() IS 'auth_uid returns the user ID of the authenticated user'; + + +-- +-- Name: billing_report_202308(public.catalog_prefix, timestamp with time zone, tstzrange); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.billing_report_202308(billed_prefix public.catalog_prefix, billed_month timestamp with time zone, free_trial_range tstzrange) RETURNS jsonb + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +#variable_conflict use_variable +declare + -- Auth checks + has_admin_grant boolean; + has_bypassrls boolean; + + -- Computed + recurring_usd_cents integer; +-- free_trial_range tstzrange; + billed_range tstzrange; + free_trial_overlap tstzrange; + + free_trial_credit numeric; + + -- Temporary line items holders for free trial calculations + task_usage_line_items jsonb = '[]'; + data_usage_line_items jsonb = '[]'; + + -- Calculating adjustments. + adjustment internal.billing_adjustments; + + -- Aggregated outputs. + line_items jsonb = '[]'; + subtotal_usd_cents integer; + + -- Free trial outputs + free_trial_gb numeric; + free_trial_hours numeric; +begin + + -- Ensure `billed_month` is the truncated start of the billed month. + billed_month = date_trunc('month', billed_month); + billed_range = tstzrange(billed_month, billed_month + '1 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 free_trial_range +-- case +-- when t.free_trial_start is null then 'empty'::tstzrange +-- -- Inclusive start, exclusive end +-- else tstzrange(date_trunc('day', t.free_trial_start), date_trunc('day', t.free_trial_start) + '1 month', '[)') +-- end +-- 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 + ; + + -- 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; + + line_items = line_items || internal.incremental_usage_report('monthly', billed_prefix, billed_range)->0->'line_items'; + + -- Does the free trial range overlap the month in question? + if not isempty(free_trial_range) and (free_trial_range && billed_range) then + free_trial_overlap = billed_range * free_trial_range; + -- Determine the total amount of data processing and task usage under `billed_prefix` + -- during the portion of `billed_month` that `free_trial_range` covers. + select into + free_trial_credit sum((line_item->>'subtotal')::numeric) + from + jsonb_array_elements( + internal.incremental_usage_report('daily', billed_prefix, free_trial_overlap) + ) as line_item; + + line_items = line_items || jsonb_build_object( + 'description', 'Free trial credit', + 'count', 1, + 'rate', free_trial_credit * -1, + 'subtotal', free_trial_credit * -1 + ); + end if; + + -- 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 +$$; + + +ALTER FUNCTION public.billing_report_202308(billed_prefix public.catalog_prefix, billed_month timestamp with time zone, free_trial_range tstzrange) OWNER TO postgres; + +-- +-- Name: create_refresh_token(boolean, interval, text); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.create_refresh_token(multi_use boolean, valid_for interval, detail text DEFAULT NULL::text) RETURNS json + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +declare + secret text; + refresh_token_row refresh_tokens; +begin + secret = gen_random_uuid(); + + insert into refresh_tokens (detail, user_id, multi_use, valid_for, hash) + values ( + detail, + auth_uid(), + multi_use, + valid_for, + crypt(secret, gen_salt('bf')) + ) returning * into refresh_token_row; + + return json_build_object( + 'id', refresh_token_row.id, + 'secret', secret + ); +commit; +end +$$; + + +ALTER FUNCTION public.create_refresh_token(multi_use boolean, valid_for interval, detail text) OWNER TO postgres; + +-- +-- Name: FUNCTION create_refresh_token(multi_use boolean, valid_for interval, detail text); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.create_refresh_token(multi_use boolean, valid_for interval, detail text) IS ' +Create a new refresh token which can then be used to generate an access token using `generate_access_token` rpc. +'; + + +-- +-- Name: draft_collections_eligible_for_deletion(public.flowid, public.flowid); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.draft_collections_eligible_for_deletion(capture_id public.flowid, draft_id public.flowid) RETURNS void + LANGUAGE plpgsql + AS $$ +begin + + insert into draft_specs (draft_id, catalog_name, expect_pub_id, spec, spec_type) + with target_collections as ( + select target_id from live_spec_flows + where source_id = capture_id + ), + collections_read as ( + select target_collections.target_id from target_collections + join live_spec_flows lsf on target_collections.target_id = lsf.source_id + ), + collections_written as ( + select target_collections.target_id from target_collections + join live_spec_flows lsf on target_collections.target_id = lsf.target_id and lsf.source_id <> capture_id + ), + ineligible_collections as ( + select target_id from collections_read + union select target_id from collections_written + ), + eligible_collection_ids as ( + select target_id from target_collections + except select target_id from ineligible_collections + ), + eligible_collections as ( + select + ls.id, + ls.catalog_name, + ls.last_pub_id + from eligible_collection_ids + join live_specs ls on eligible_collection_ids.target_id = ls.id + ) + select draft_id, catalog_name, last_pub_id, null, null from eligible_collections; + +end; +$$; + + +ALTER FUNCTION public.draft_collections_eligible_for_deletion(capture_id public.flowid, draft_id public.flowid) OWNER TO postgres; + +-- +-- Name: FUNCTION draft_collections_eligible_for_deletion(capture_id public.flowid, draft_id public.flowid); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.draft_collections_eligible_for_deletion(capture_id public.flowid, draft_id public.flowid) IS ' +draft_collections_eligible_for_deletion facilitates the deletion of a capture and its associated collections +in the same publication by populating the specified draft with the collections eligible for deletion. +The specified draft should contain the capture pending deletion. +'; + + +-- +-- Name: exchange_directive_token(uuid); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.exchange_directive_token(bearer_token uuid) RETURNS public.exchanged_directive + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +declare + directive_row directives; + applied_row applied_directives; +begin + + -- Note that uses_remaining could be null, and in that case `uses_remaining - 1` + -- would also evaluate to null. This means that we don't actually update + -- uses_remaining here if the current value is null. + -- We also intentionally leave the bearer_token in place when uses_remaining + -- drops to 0, because it's possible that something may come along and + -- increase uses_remaining again. + update directives + set uses_remaining = uses_remaining - 1 + where directives.token = bearer_token + returning * into directive_row; + + if not found then + raise 'Bearer token % is not valid', bearer_token + using errcode = 'check_violation'; + end if; + + if directive_row.uses_remaining is not null and directive_row.uses_remaining < 0 then + raise 'System quota has been reached, please contact support@estuary.dev in order to proceed.' + using errcode = 'check_violation'; + end if; + + insert into applied_directives (directive_id, user_id) + values (directive_row.id, auth.uid()) + returning * into applied_row; + + return (directive_row, applied_row); +end; +$$; + + +ALTER FUNCTION public.exchange_directive_token(bearer_token uuid) OWNER TO postgres; + +-- +-- Name: FUNCTION exchange_directive_token(bearer_token uuid); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.exchange_directive_token(bearer_token uuid) IS ' +exchange_directive_token allows a user to turn in a directive bearer token +and, in exchange, create an application of that directive. + +If the supplied token is valid then a new row is created in `applied_directives`. +The user must next update it with their supplied claims. + +Having applied a directive through its token, the user is now able to view +the directive. As a convience, this function also returns the directive +along with the newly-created applied_directive row. +'; + + +-- +-- Name: gateway_auth_token(text[]); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.gateway_auth_token(VARIADIC prefixes text[]) RETURNS TABLE(token text, gateway_url text) + LANGUAGE plpgsql STABLE SECURITY DEFINER + AS $$ +declare + -- The number of distinct prefixes (i.e. scopes) that were requested. + requested_prefixes int := (select count(distinct p) from unnest(prefixes) p); + -- The distinct prefixes, filtered by whether or not they are authorized. + authorized_prefixes text[]; +begin + + select array_agg(distinct p) into authorized_prefixes + from + unnest(prefixes) as p + join auth_roles() as r on starts_with(p, r.role_prefix); + + -- authorized_prefixes will be null when _none_ of the requested prefixes are authorized. + -- In that case the array_length comparison won't work, so we need an explicit null check. + if authorized_prefixes is null or array_length(authorized_prefixes, 1) != requested_prefixes then + -- errcode 28000 causes potgrest 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 all of the requested scopes' using errcode = 28000; + end if; + + return query select internal.sign_jwt( + json_build_object( + 'exp', trunc(extract(epoch from (now() + interval '1 hour'))), + 'iat', trunc(extract(epoch from (now()))), + 'operation', 'read', + 'prefixes', authorized_prefixes, + 'sub', auth_uid() + ) + ) as token, internal.gateway_endpoint_url() as gateway_url; +end; +$$; + + +ALTER FUNCTION public.gateway_auth_token(VARIADIC prefixes text[]) OWNER TO postgres; + +-- +-- Name: FUNCTION gateway_auth_token(VARIADIC prefixes text[]); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.gateway_auth_token(VARIADIC prefixes text[]) IS 'gateway_auth_token returns a jwt that can be used with the Data Plane Gateway to interact directly with Gazette RPCs.'; + + +-- +-- Name: generate_access_token(public.flowid, text); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.generate_access_token(refresh_token_id public.flowid, secret text) RETURNS json + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +declare + rt refresh_tokens; + rt_new_secret text; + access_token text; +begin + + select * into rt from refresh_tokens where + refresh_tokens.id = refresh_token_id; + + if not found then + raise 'could not find refresh_token with the given `refresh_token_id`'; + end if; + + if rt.hash <> crypt(secret, rt.hash) then + raise 'invalid secret provided'; + end if; + + if (rt.updated_at + rt.valid_for) < now() then + raise 'refresh_token has expired.'; + end if; + + select sign(json_build_object( + 'exp', trunc(extract(epoch from (now() + interval '1 hour'))), + 'iat', trunc(extract(epoch from (now()))), + 'sub', rt.user_id, + 'role', 'authenticated' + ), internal.access_token_jwt_secret()) into access_token + limit 1; + + if rt.multi_use = false then + rt_new_secret = gen_random_uuid(); + update refresh_tokens + set + hash = crypt(rt_new_secret, gen_salt('bf')), + uses = (uses + 1), + updated_at = clock_timestamp() + where refresh_tokens.id = rt.id; + else + -- re-set the updated_at timer so the token's validity is refreshed + update refresh_tokens + set + uses = (uses + 1), + updated_at = clock_timestamp() + where refresh_tokens.id = rt.id; + end if; + + if rt_new_secret is null then + return json_build_object( + 'access_token', access_token + ); + else + return json_build_object( + 'access_token', access_token, + 'refresh_token', json_build_object( + 'id', rt.id, + 'secret', rt_new_secret + ) + ); + end if; +commit; +end +$$; + + +ALTER FUNCTION public.generate_access_token(refresh_token_id public.flowid, secret text) OWNER TO postgres; + +-- +-- Name: FUNCTION generate_access_token(refresh_token_id public.flowid, secret text); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.generate_access_token(refresh_token_id public.flowid, secret text) IS ' +Given a refresh_token, generates a new access_token. +If the refresh_token is not multi-use, the token''s secret is rotated. +If the refresh_token is multi-use, we reset its validity period by updating its `updated_at` column +'; + + +-- +-- Name: generate_opengraph_value(jsonb, jsonb, text); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.generate_opengraph_value(opengraph_raw jsonb, opengraph_patch jsonb, field text) RETURNS public.jsonb_internationalized_value + LANGUAGE plpgsql IMMUTABLE + AS $$ +BEGIN + RETURN json_build_object('en-US',internal.jsonb_merge_patch(opengraph_raw, opengraph_patch) #>> ('{"en-US", "'|| field ||'"}')::text[]); +END +$$; + + +ALTER FUNCTION public.generate_opengraph_value(opengraph_raw jsonb, opengraph_patch jsonb, field text) OWNER TO postgres; + +-- +-- Name: prune_unchanged_draft_specs(public.flowid); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.prune_unchanged_draft_specs(prune_draft_id public.flowid) RETURNS TABLE(catalog_name public.catalog_name, spec_type public.catalog_spec_type, live_spec_md5 text, draft_spec_md5 text, inferred_schema_md5 text, live_inferred_schema_md5 text) + LANGUAGE sql + AS $$ + with to_prune as ( + select * from unchanged_draft_specs u where u.draft_id = prune_draft_id + ), + del as ( + delete from draft_specs ds + where ds.draft_id = prune_draft_id + and ds.catalog_name in (select catalog_name from to_prune) + ) + select + catalog_name, + spec_type, + live_spec_md5, + draft_spec_md5, + inferred_schema_md5, + live_inferred_schema_md5 + from to_prune +$$; + + +ALTER FUNCTION public.prune_unchanged_draft_specs(prune_draft_id public.flowid) OWNER TO postgres; + +-- +-- Name: FUNCTION prune_unchanged_draft_specs(prune_draft_id public.flowid); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.prune_unchanged_draft_specs(prune_draft_id public.flowid) IS 'Deletes draft_specs belonging to the given draft_id that are identical + to the published live_specs. For collection specs that use inferred schemas, + draft_specs will only be deleted if the inferred schema also remains identical.'; + + +-- +-- Name: republish_prefix(public.catalog_prefix); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.republish_prefix(prefix public.catalog_prefix) RETURNS public.flowid + LANGUAGE plpgsql + AS $$ +declare + draft_id flowid; + pub_id flowid; +begin + insert into drafts default values returning id into draft_id; + insert into draft_specs (draft_id, catalog_name, spec_type, spec, expect_pub_id) + select draft_id, catalog_name, spec_type, spec, last_pub_id as expect_pub_id + from live_specs + where starts_with(catalog_name, prefix) and spec_type is not null; + + insert into publications (draft_id) values (draft_id) returning id into pub_id; + return pub_id; +end; +$$; + + +ALTER FUNCTION public.republish_prefix(prefix public.catalog_prefix) OWNER TO postgres; + +-- +-- Name: FUNCTION republish_prefix(prefix public.catalog_prefix); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.republish_prefix(prefix public.catalog_prefix) IS 'Creates a publication of every task and collection under the given prefix. This will not modify any +of the specs, and will set expect_pub_id to ensure that the publication does not overwrite changes +from other publications. This is intended to be called after an update to the storage mappings of +the prefix to apply the updated mappings.'; + + +-- +-- Name: tier_line_items(numeric, integer[], text, text); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.tier_line_items(amount numeric, tiers integer[], name text, unit text) RETURNS jsonb + LANGUAGE plpgsql + AS $_$ +declare + o_line_items jsonb = '[]'; -- Output variable. + tier_count numeric; + tier_pivot integer; + tier_rate integer; +begin + + for idx in 1..array_length(tiers, 1) by 2 loop + tier_rate = tiers[idx]; + tier_pivot = tiers[idx+1]; + tier_count = least(amount, tier_pivot); + amount = amount - tier_count; + + o_line_items = o_line_items || jsonb_build_object( + 'description', format( + case + when tier_pivot is null then '%1$s (at %4$s/%2$s)' -- Data processing (at $0.50/GB) + when idx = 1 then '%1s (first %3$s %2$ss at %4$s/%2$s)' -- Data processing (first 30 GBs at $0.50/GB) + else '%1$s (next %3$s %2$ss at %4$s/%2$s)' -- Data processing (next 6 GBs at $0.25/GB) + end, + name, + unit, + tier_pivot, + (tier_rate / 100.0)::money + ), + 'count', tier_count, + 'rate', tier_rate, + 'subtotal', round(tier_count * tier_rate) + ); + end loop; + + return o_line_items; + +end +$_$; + + +ALTER FUNCTION public.tier_line_items(amount numeric, tiers integer[], name text, unit text) OWNER TO postgres; + +-- +-- Name: user_info_summary(); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.user_info_summary() RETURNS json + LANGUAGE sql + AS $$ + with all_grants(role_prefix, capability) as ( + select role_prefix, capability from auth_roles() + ) + select json_build_object( + 'hasDemoAccess', exists(select 1 from all_grants where role_prefix = 'demo/' and capability >= 'read'), + 'hasSupportAccess', exists(select 1 from all_grants where role_prefix = 'estuary_support/' and capability >= 'admin'), + 'hasAnyAccess', exists(select 1 from all_grants) + ) + +$$; + + +ALTER FUNCTION public.user_info_summary() OWNER TO postgres; + +-- +-- Name: FUNCTION user_info_summary(); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.user_info_summary() IS 'Returns a JSON object with a few computed attributes for the UI. +These would otherwise require the UI to fetch the complete list of authorized grants, +which can be quite slow for users with many grants. Returns a response like: +{ + hasDemoAccess: boolean, //true if the user has `read` on `demo/` tenant, + hasSupportAccess: boolean, // true if user has `admin` on `estuary_support/` + hasAnyAccess: boolean, // true if user has any authorization grants at all +}'; + + +-- +-- Name: log_lines; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal.log_lines ( + log_line text NOT NULL, + logged_at timestamp with time zone DEFAULT now() NOT NULL, + stream text NOT NULL, + token uuid NOT NULL +); + + +ALTER TABLE internal.log_lines OWNER TO postgres; + +-- +-- Name: TABLE log_lines; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON TABLE internal.log_lines IS 'Logs produced by server-side operations'; + + +-- +-- Name: COLUMN log_lines.log_line; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.log_lines.log_line IS 'Logged line'; + + +-- +-- Name: COLUMN log_lines.logged_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.log_lines.logged_at IS 'Time at which the log was collected'; + + +-- +-- Name: COLUMN log_lines.stream; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.log_lines.stream IS 'Identifier of the log stream within the job'; + + +-- +-- Name: COLUMN log_lines.token; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.log_lines.token IS 'Bearer token which demarks and provides accesss to a set of logs'; + + +-- +-- Name: view_logs(uuid); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.view_logs(bearer_token uuid) RETURNS SETOF internal.log_lines + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +begin + return query select * from internal.log_lines where internal.log_lines.token = bearer_token; +end; +$$; + + +ALTER FUNCTION public.view_logs(bearer_token uuid) OWNER TO postgres; + +-- +-- Name: FUNCTION view_logs(bearer_token uuid); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.view_logs(bearer_token uuid) IS 'view_logs accepts a log bearer_token and returns its matching log lines'; + + +-- +-- Name: view_user_profile(uuid); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.view_user_profile(bearer_user_id uuid) RETURNS public.user_profile + LANGUAGE sql STABLE SECURITY DEFINER + AS $$ + select + user_id, + email, + full_name, + avatar_url + from internal.user_profiles where user_id = bearer_user_id; +$$; + + +ALTER FUNCTION public.view_user_profile(bearer_user_id uuid) OWNER TO postgres; + +-- +-- Name: FUNCTION view_user_profile(bearer_user_id uuid); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.view_user_profile(bearer_user_id uuid) IS 'view_user_profile returns the profile of the given user ID'; + + +-- +-- Name: _model; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal._model ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL +); + + +ALTER TABLE internal._model OWNER TO postgres; + +-- +-- Name: TABLE _model; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON TABLE internal._model IS 'Model table for the creation of other tables'; + + +-- +-- Name: COLUMN _model.created_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN _model.detail; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN _model.id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model.id IS 'ID of the record'; + + +-- +-- Name: COLUMN _model.updated_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: _model_async; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal._model_async ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + job_status public.jsonb_obj DEFAULT '{"type": "queued"}'::jsonb NOT NULL, + logs_token uuid DEFAULT gen_random_uuid() NOT NULL, + background boolean DEFAULT false NOT NULL +); + + +ALTER TABLE internal._model_async OWNER TO postgres; + +-- +-- Name: TABLE _model_async; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON TABLE internal._model_async IS 'Model table for the creation of other tables representing a server-side operation'; + + +-- +-- Name: COLUMN _model_async.created_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model_async.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN _model_async.detail; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model_async.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN _model_async.id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model_async.id IS 'ID of the record'; + + +-- +-- Name: COLUMN _model_async.updated_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model_async.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN _model_async.job_status; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model_async.job_status IS 'Server-side job executation status of the record'; + + +-- +-- Name: COLUMN _model_async.logs_token; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model_async.logs_token IS 'Bearer token for accessing logs of the server-side operation'; + + +-- +-- Name: COLUMN _model_async.background; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal._model_async.background IS 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; + + +-- +-- Name: alert_data_processing; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.alert_data_processing ( + catalog_name public.catalog_name NOT NULL, + evaluation_interval interval NOT NULL +); + + +ALTER TABLE public.alert_data_processing OWNER TO postgres; + +-- +-- Name: alert_subscriptions; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.alert_subscriptions ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + catalog_prefix public.catalog_prefix NOT NULL, + email text +); + + +ALTER TABLE public.alert_subscriptions OWNER TO postgres; + +-- +-- Name: COLUMN alert_subscriptions.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.alert_subscriptions.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN alert_subscriptions.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.alert_subscriptions.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN alert_subscriptions.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.alert_subscriptions.id IS 'ID of the record'; + + +-- +-- Name: COLUMN alert_subscriptions.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.alert_subscriptions.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: catalog_stats; Type: TABLE; Schema: public; Owner: stats_loader +-- + +CREATE TABLE public.catalog_stats ( + catalog_name public.catalog_name NOT NULL, + grain text NOT NULL, + ts timestamp with time zone NOT NULL, + bytes_written_by_me bigint DEFAULT 0 NOT NULL, + docs_written_by_me bigint DEFAULT 0 NOT NULL, + bytes_read_by_me bigint DEFAULT 0 NOT NULL, + docs_read_by_me bigint DEFAULT 0 NOT NULL, + bytes_written_to_me bigint DEFAULT 0 NOT NULL, + docs_written_to_me bigint DEFAULT 0 NOT NULL, + bytes_read_from_me bigint DEFAULT 0 NOT NULL, + docs_read_from_me bigint DEFAULT 0 NOT NULL, + usage_seconds integer DEFAULT 0 NOT NULL, + warnings integer DEFAULT 0 NOT NULL, + errors integer DEFAULT 0 NOT NULL, + failures integer DEFAULT 0 NOT NULL, + flow_document json NOT NULL +) +PARTITION BY LIST (grain); + + +ALTER TABLE public.catalog_stats OWNER TO stats_loader; + +-- +-- Name: TABLE catalog_stats; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON TABLE public.catalog_stats IS 'Statistics for Flow catalogs'; + + +-- +-- Name: COLUMN catalog_stats.grain; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.grain IS ' +Time grain that stats are summed over. + +One of "monthly", "daily", or "hourly". +'; + + +-- +-- Name: COLUMN catalog_stats.ts; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.ts IS ' +Timestamp indicating the start time of the time grain. + +Monthly grains start on day 1 of the month, at hour 0 and minute 0. +Daily grains start on the day, at hour 0 and minute 0. +Hourly grains start on the hour, at minute 0. +'; + + +-- +-- Name: COLUMN catalog_stats.bytes_written_by_me; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.bytes_written_by_me IS 'Bytes written by this catalog, summed over the time grain.'; + + +-- +-- Name: COLUMN catalog_stats.docs_written_by_me; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.docs_written_by_me IS 'Documents written by this catalog, summed over the time grain.'; + + +-- +-- Name: COLUMN catalog_stats.bytes_read_by_me; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.bytes_read_by_me IS 'Bytes read by this catalog, summed over the time grain.'; + + +-- +-- Name: COLUMN catalog_stats.docs_read_by_me; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.docs_read_by_me IS 'Documents read by this catalog, summed over the time grain.'; + + +-- +-- Name: COLUMN catalog_stats.bytes_written_to_me; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.bytes_written_to_me IS 'Bytes written to this catalog, summed over the time grain.'; + + +-- +-- Name: COLUMN catalog_stats.docs_written_to_me; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.docs_written_to_me IS 'Documents written to this catalog, summed over the time grain.'; + + +-- +-- Name: COLUMN catalog_stats.bytes_read_from_me; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.bytes_read_from_me IS 'Bytes read from this catalog, summed over the time grain.'; + + +-- +-- Name: COLUMN catalog_stats.docs_read_from_me; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.docs_read_from_me IS 'Documents read from this catalog, summed over the time grain.'; + + +-- +-- Name: COLUMN catalog_stats.usage_seconds; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.usage_seconds IS 'Metered usage of this catalog task.'; + + +-- +-- Name: COLUMN catalog_stats.flow_document; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.catalog_stats.flow_document IS 'Aggregated statistics document for the given catalog name and grain'; + + +-- +-- Name: catalog_stats_hourly; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.catalog_stats_hourly ( + catalog_name public.catalog_name NOT NULL, + grain text NOT NULL, + ts timestamp with time zone NOT NULL, + bytes_written_by_me bigint DEFAULT 0 NOT NULL, + docs_written_by_me bigint DEFAULT 0 NOT NULL, + bytes_read_by_me bigint DEFAULT 0 NOT NULL, + docs_read_by_me bigint DEFAULT 0 NOT NULL, + bytes_written_to_me bigint DEFAULT 0 NOT NULL, + docs_written_to_me bigint DEFAULT 0 NOT NULL, + bytes_read_from_me bigint DEFAULT 0 NOT NULL, + docs_read_from_me bigint DEFAULT 0 NOT NULL, + usage_seconds integer DEFAULT 0 NOT NULL, + warnings integer DEFAULT 0 NOT NULL, + errors integer DEFAULT 0 NOT NULL, + failures integer DEFAULT 0 NOT NULL, + flow_document json NOT NULL +); + + +ALTER TABLE public.catalog_stats_hourly OWNER TO postgres; + +-- +-- Name: live_specs; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.live_specs ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + catalog_name public.catalog_name NOT NULL, + connector_image_name text, + connector_image_tag text, + last_pub_id public.flowid NOT NULL, + reads_from text[], + spec json, + spec_type public.catalog_spec_type, + writes_to text[], + last_build_id public.flowid NOT NULL, + md5 text GENERATED ALWAYS AS (md5(TRIM(BOTH FROM (spec)::text))) STORED, + built_spec json, + inferred_schema_md5 text, + controller_next_run timestamp with time zone, + data_plane_id public.flowid DEFAULT '0e:8e:17:d0:4f:ac:d4:00'::macaddr8 NOT NULL, + journal_template_name text GENERATED ALWAYS AS (((built_spec -> 'partitionTemplate'::text) ->> 'name'::text)) STORED, + shard_template_id text GENERATED ALWAYS AS (COALESCE(((built_spec -> 'shardTemplate'::text) ->> 'id'::text), (((built_spec -> 'derivation'::text) -> 'shardTemplate'::text) ->> 'id'::text))) STORED, + dependency_hash text +); + + +ALTER TABLE public.live_specs OWNER TO postgres; + +-- +-- Name: TABLE live_specs; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.live_specs IS 'Live (in other words, current) catalog specifications of the platform'; + + +-- +-- Name: COLUMN live_specs.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN live_specs.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN live_specs.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.id IS 'ID of the record'; + + +-- +-- Name: COLUMN live_specs.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN live_specs.catalog_name; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.catalog_name IS 'Catalog name of this specification'; + + +-- +-- Name: COLUMN live_specs.connector_image_name; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.connector_image_name IS 'OCI (Docker) connector image name used by this specification'; + + +-- +-- Name: COLUMN live_specs.connector_image_tag; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.connector_image_tag IS 'OCI (Docker) connector image tag used by this specification'; + + +-- +-- Name: COLUMN live_specs.last_pub_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.last_pub_id IS 'Last publication ID which updated this specification'; + + +-- +-- Name: COLUMN live_specs.reads_from; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.reads_from IS ' +List of collections read by this catalog task specification, +or NULL if not applicable to this specification type. +These adjacencies are also indexed within `live_spec_flows`. +'; + + +-- +-- Name: COLUMN live_specs.spec; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.spec IS 'Serialized catalog specification, or NULL if this specification is deleted'; + + +-- +-- Name: COLUMN live_specs.spec_type; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.spec_type IS 'Type of this catalog specification, or NULL if this specification is deleted'; + + +-- +-- Name: COLUMN live_specs.writes_to; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.writes_to IS ' +List of collections written by this catalog task specification, +or NULL if not applicable to this specification type. +These adjacencies are also indexed within `live_spec_flows`. +'; + + +-- +-- Name: COLUMN live_specs.last_build_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.last_build_id IS ' +Last publication ID under which this specification was built and activated +into the data-plane, even if it was not necessarily updated. + +A specification may be included in a publication which did not directly +change it simply because of its connection to other specifications which +were part of that publication: Flow identifies connected specifications +in order to holistically verify and test their combined behaviors. +'; + + +-- +-- Name: COLUMN live_specs.built_spec; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.built_spec IS 'Built specification for this catalog'; + + +-- +-- Name: COLUMN live_specs.inferred_schema_md5; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.inferred_schema_md5 IS 'The md5 sum of the inferred schema that was published with this spec'; + + +-- +-- Name: COLUMN live_specs.controller_next_run; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.controller_next_run IS 'The next time the controller for this spec should run.'; + + +-- +-- Name: COLUMN live_specs.dependency_hash; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_specs.dependency_hash IS 'An hash of all the dependencies which were used to build this spec. +Any change to the _model_ of a dependency will change this hash. +Changes to the built spec of a dependency without an accompanying +model change will not change the hash.'; + + +-- +-- Name: alert_data_movement_stalled; Type: VIEW; Schema: internal; Owner: postgres +-- + +CREATE VIEW internal.alert_data_movement_stalled AS + SELECT 'data_movement_stalled'::public.alert_type AS alert_type, + alert_data_processing.catalog_name, + json_build_object('bytes_processed', (COALESCE(sum(((catalog_stats_hourly.bytes_written_by_me + catalog_stats_hourly.bytes_written_to_me) + catalog_stats_hourly.bytes_read_by_me)), (0)::numeric))::bigint, 'recipients', array_agg(DISTINCT jsonb_build_object('email', alert_subscriptions.email, 'full_name', (users.raw_user_meta_data ->> 'full_name'::text))), 'evaluation_interval', alert_data_processing.evaluation_interval, 'spec_type', live_specs.spec_type) AS arguments, + true AS firing + FROM ((((public.alert_data_processing + LEFT JOIN public.live_specs ON ((((alert_data_processing.catalog_name)::text = (live_specs.catalog_name)::text) AND (live_specs.spec IS NOT NULL) AND ((((live_specs.spec -> 'shards'::text) ->> 'disable'::text))::boolean IS NOT TRUE)))) + LEFT JOIN public.catalog_stats_hourly ON ((((alert_data_processing.catalog_name)::text = (catalog_stats_hourly.catalog_name)::text) AND (catalog_stats_hourly.ts >= date_trunc('hour'::text, (now() - alert_data_processing.evaluation_interval)))))) + LEFT JOIN public.alert_subscriptions ON ((((alert_data_processing.catalog_name)::text ^@ (alert_subscriptions.catalog_prefix)::text) AND (alert_subscriptions.email IS NOT NULL)))) + LEFT JOIN auth.users ON ((((users.email)::text = alert_subscriptions.email) AND (users.is_sso_user IS FALSE)))) + WHERE (live_specs.created_at <= date_trunc('hour'::text, (now() - alert_data_processing.evaluation_interval))) + GROUP BY alert_data_processing.catalog_name, alert_data_processing.evaluation_interval, live_specs.spec_type + HAVING ((COALESCE(sum(((catalog_stats_hourly.bytes_written_by_me + catalog_stats_hourly.bytes_written_to_me) + catalog_stats_hourly.bytes_read_by_me)), (0)::numeric))::bigint = 0); + + +ALTER VIEW internal.alert_data_movement_stalled OWNER TO postgres; + +-- +-- Name: tenants; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.tenants ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + tenant public.catalog_tenant NOT NULL, + tasks_quota integer DEFAULT 10 NOT NULL, + collections_quota integer DEFAULT 500 NOT NULL, + data_tiers integer[] DEFAULT '{50}'::integer[] NOT NULL, + usage_tiers integer[] DEFAULT '{14,4464,7}'::integer[] NOT NULL, + recurring_usd_cents integer DEFAULT 0 NOT NULL, + trial_start date, + payment_provider public.payment_provider_type DEFAULT 'stripe'::public.payment_provider_type, + gcm_account_id uuid, + hide_preview boolean DEFAULT false NOT NULL, + CONSTRAINT "data_tiers is odd" CHECK (((array_length(data_tiers, 1) % 2) = 1)), + CONSTRAINT "usage_tiers is odd" CHECK (((array_length(usage_tiers, 1) % 2) = 1)) +); + + +ALTER TABLE public.tenants OWNER TO postgres; + +-- +-- Name: TABLE tenants; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.tenants IS ' +A tenant is the top-level unit of organization in the Flow catalog namespace. +'; + + +-- +-- Name: COLUMN tenants.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN tenants.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN tenants.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.id IS 'ID of the record'; + + +-- +-- Name: COLUMN tenants.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN tenants.tenant; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.tenant IS 'Catalog tenant identified by this record'; + + +-- +-- Name: COLUMN tenants.tasks_quota; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.tasks_quota IS 'Maximum number of active tasks that the tenant may have'; + + +-- +-- Name: COLUMN tenants.collections_quota; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.collections_quota IS 'Maximum number of collections that the tenant may have'; + + +-- +-- Name: COLUMN tenants.data_tiers; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.data_tiers IS ' +Tiered data processing volumes and prices. + +Structured as an odd-length array of a price (in cents) followed by a volume (in GB). +For example, `{50, 1024, 30, 2048, 20}` is interpreted as: + * $0.50 per GB for the first TB (1,024 GB). + * $0.30 per GB for the next two TB (3TB cumulative). + * $0.20 per GB thereafter. +'; + + +-- +-- Name: COLUMN tenants.usage_tiers; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.usage_tiers IS ' +Tiered task usage quantities and prices. + +Structured as an odd-length array of a price (in cents) followed by a quantity (in hours). +For example, `{30, 1440, 20, 2880, 15}` is interpreted as: + * $0.30 per hour for the first 1,440 hours. + * $0.20 per hour for the next 2,880 hours (4,320 hours total). + * $0.15 per hour thereafter. +'; + + +-- +-- Name: COLUMN tenants.recurring_usd_cents; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.recurring_usd_cents IS ' +Recurring monthly cost incurred by a tenant under a contracted relationship, in US cents (1/100ths of a USD). +'; + + +-- +-- Name: COLUMN tenants.hide_preview; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.tenants.hide_preview IS ' +Hide data preview in the collections page for this tenant, used as a measure for preventing users with access to this tenant from viewing sensitive data in collections +'; + + +-- +-- Name: alert_free_trial; Type: VIEW; Schema: internal; Owner: postgres +-- + +CREATE VIEW internal.alert_free_trial AS + SELECT 'free_trial'::public.alert_type AS alert_type, + (((tenants.tenant)::text || 'alerts/free_trial'::text))::public.catalog_name AS catalog_name, + json_build_object('tenant', tenants.tenant, 'recipients', array_agg(DISTINCT jsonb_build_object('email', alert_subscriptions.email, 'full_name', (users.raw_user_meta_data ->> 'full_name'::text))), 'trial_start', tenants.trial_start, 'trial_end', ((tenants.trial_start + '1 mon'::interval))::date, 'has_credit_card', bool_or((customers."invoice_settings/default_payment_method" IS NOT NULL))) AS arguments, + ((tenants.trial_start IS NOT NULL) AND ((now() - (tenants.trial_start)::timestamp with time zone) < '1 mon'::interval) AND (tenants.trial_start <= now())) AS firing + FROM (((public.tenants + LEFT JOIN public.alert_subscriptions ON ((((alert_subscriptions.catalog_prefix)::text ^@ (tenants.tenant)::text) AND (alert_subscriptions.email IS NOT NULL)))) + LEFT JOIN stripe.customers ON ((customers.name = (tenants.tenant)::text))) + LEFT JOIN auth.users ON ((((users.email)::text = alert_subscriptions.email) AND (users.is_sso_user IS FALSE)))) + GROUP BY tenants.tenant, tenants.trial_start; + + +ALTER VIEW internal.alert_free_trial OWNER TO postgres; + +-- +-- Name: alert_free_trial_ending; Type: VIEW; Schema: internal; Owner: postgres +-- + +CREATE VIEW internal.alert_free_trial_ending AS + SELECT 'free_trial_ending'::public.alert_type AS alert_type, + (((tenants.tenant)::text || 'alerts/free_trial_ending'::text))::public.catalog_name AS catalog_name, + json_build_object('tenant', tenants.tenant, 'recipients', array_agg(DISTINCT jsonb_build_object('email', alert_subscriptions.email, 'full_name', (users.raw_user_meta_data ->> 'full_name'::text))), 'trial_start', tenants.trial_start, 'trial_end', ((tenants.trial_start + '1 mon'::interval))::date, 'has_credit_card', bool_or((customers."invoice_settings/default_payment_method" IS NOT NULL))) AS arguments, + ((tenants.trial_start IS NOT NULL) AND ((now() - (tenants.trial_start)::timestamp with time zone) >= ('1 mon'::interval - '5 days'::interval)) AND ((now() - (tenants.trial_start)::timestamp with time zone) < ('1 mon'::interval - '4 days'::interval)) AND (tenants.trial_start <= now())) AS firing + FROM (((public.tenants + LEFT JOIN public.alert_subscriptions ON ((((alert_subscriptions.catalog_prefix)::text ^@ (tenants.tenant)::text) AND (alert_subscriptions.email IS NOT NULL)))) + LEFT JOIN stripe.customers ON ((customers.name = (tenants.tenant)::text))) + LEFT JOIN auth.users ON ((((users.email)::text = alert_subscriptions.email) AND (users.is_sso_user IS FALSE)))) + GROUP BY tenants.tenant, tenants.trial_start; + + +ALTER VIEW internal.alert_free_trial_ending OWNER TO postgres; + +-- +-- Name: alert_free_trial_stalled; Type: VIEW; Schema: internal; Owner: postgres +-- + +CREATE VIEW internal.alert_free_trial_stalled AS + SELECT 'free_trial_stalled'::public.alert_type AS alert_type, + (((tenants.tenant)::text || 'alerts/free_trial_stalled'::text))::public.catalog_name AS catalog_name, + json_build_object('tenant', tenants.tenant, 'recipients', array_agg(DISTINCT jsonb_build_object('email', alert_subscriptions.email, 'full_name', (users.raw_user_meta_data ->> 'full_name'::text))), 'trial_start', tenants.trial_start, 'trial_end', ((tenants.trial_start + '1 mon'::interval))::date) AS arguments, + true AS firing + FROM (((public.tenants + LEFT JOIN public.alert_subscriptions ON ((((alert_subscriptions.catalog_prefix)::text ^@ (tenants.tenant)::text) AND (alert_subscriptions.email IS NOT NULL)))) + LEFT JOIN stripe.customers ON ((customers.name = (tenants.tenant)::text))) + LEFT JOIN auth.users ON ((((users.email)::text = alert_subscriptions.email) AND (users.is_sso_user IS FALSE)))) + WHERE ((tenants.trial_start IS NOT NULL) AND ((now() - (tenants.trial_start)::timestamp with time zone) >= ('1 mon'::interval + '5 days'::interval)) AND (tenants.trial_start <= now()) AND (customers."invoice_settings/default_payment_method" IS NULL)) + GROUP BY tenants.tenant, tenants.trial_start; + + +ALTER VIEW internal.alert_free_trial_stalled OWNER TO postgres; + +-- +-- Name: alert_missing_payment_method; Type: VIEW; Schema: internal; Owner: postgres +-- + +CREATE VIEW internal.alert_missing_payment_method AS + SELECT 'missing_payment_method'::public.alert_type AS alert_type, + (((tenants.tenant)::text || 'alerts/missing_payment_method'::text))::public.catalog_name AS catalog_name, + json_build_object('tenant', tenants.tenant, 'recipients', array_agg(DISTINCT jsonb_build_object('email', alert_subscriptions.email, 'full_name', (users.raw_user_meta_data ->> 'full_name'::text))), 'trial_start', tenants.trial_start, 'trial_end', ((tenants.trial_start + '1 mon'::interval))::date, 'plan_state', + CASE + WHEN (tenants.trial_start IS NULL) THEN 'free_tier'::text + WHEN ((now() - (tenants.trial_start)::timestamp with time zone) < '1 mon'::interval) THEN 'free_trial'::text + ELSE 'paid'::text + END) AS arguments, + bool_or((customers."invoice_settings/default_payment_method" IS NULL)) AS firing + FROM (((public.tenants + LEFT JOIN public.alert_subscriptions ON ((((alert_subscriptions.catalog_prefix)::text ^@ (tenants.tenant)::text) AND (alert_subscriptions.email IS NOT NULL)))) + LEFT JOIN stripe.customers ON ((customers.name = (tenants.tenant)::text))) + LEFT JOIN auth.users ON ((((users.email)::text = alert_subscriptions.email) AND (users.is_sso_user IS FALSE)))) + GROUP BY tenants.tenant, tenants.trial_start; + + +ALTER VIEW internal.alert_missing_payment_method OWNER TO postgres; + +-- +-- Name: billing_adjustments; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal.billing_adjustments ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + tenant public.catalog_tenant NOT NULL, + billed_month timestamp with time zone NOT NULL, + usd_cents integer NOT NULL, + authorizer text NOT NULL, + CONSTRAINT "billed_month must be at a month boundary" CHECK ((billed_month = date_trunc('month'::text, billed_month))) +); + + +ALTER TABLE internal.billing_adjustments OWNER TO postgres; + +-- +-- Name: TABLE billing_adjustments; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON TABLE internal.billing_adjustments IS 'Internal table for authorized adjustments to tenant invoices, such as make-goods or negotiated service fees'; + + +-- +-- Name: COLUMN billing_adjustments.created_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_adjustments.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN billing_adjustments.detail; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_adjustments.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN billing_adjustments.id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_adjustments.id IS 'ID of the record'; + + +-- +-- Name: COLUMN billing_adjustments.updated_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_adjustments.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN billing_adjustments.tenant; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_adjustments.tenant IS 'Tenant which is being credited or debited.'; + + +-- +-- Name: COLUMN billing_adjustments.billed_month; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_adjustments.billed_month IS 'Month to which the adjustment is applied'; + + +-- +-- Name: COLUMN billing_adjustments.usd_cents; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_adjustments.usd_cents IS 'Amount of adjustment. Positive values make the bill larger, negative values make it smaller'; + + +-- +-- Name: COLUMN billing_adjustments.authorizer; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_adjustments.authorizer IS 'Estuary employee who authorizes the adjustment'; + + +-- +-- Name: billing_historicals; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal.billing_historicals ( + tenant public.catalog_tenant NOT NULL, + billed_month timestamp with time zone NOT NULL, + report jsonb NOT NULL, + CONSTRAINT billing_historicals_billed_month_check CHECK ((date_trunc('month'::text, billed_month) = billed_month)) +); + + +ALTER TABLE internal.billing_historicals OWNER TO postgres; + +-- +-- Name: TABLE billing_historicals; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON TABLE internal.billing_historicals IS 'Historical billing statements frozen from `billing_report_202308()`.'; + + +-- +-- Name: COLUMN billing_historicals.tenant; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_historicals.tenant IS 'The tenant for this billing statement'; + + +-- +-- Name: COLUMN billing_historicals.billed_month; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_historicals.billed_month IS 'The month for this billing statement'; + + +-- +-- Name: COLUMN billing_historicals.report; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.billing_historicals.report IS 'The historical billing report generated by billing_report_202308()'; + + +-- +-- Name: gateway_auth_keys; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal.gateway_auth_keys ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + secret_key text +); + + +ALTER TABLE internal.gateway_auth_keys OWNER TO postgres; + +-- +-- Name: COLUMN gateway_auth_keys.created_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gateway_auth_keys.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN gateway_auth_keys.detail; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gateway_auth_keys.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN gateway_auth_keys.id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gateway_auth_keys.id IS 'ID of the record'; + + +-- +-- Name: COLUMN gateway_auth_keys.updated_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gateway_auth_keys.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: gateway_endpoints; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal.gateway_endpoints ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + name text, + url text +); + + +ALTER TABLE internal.gateway_endpoints OWNER TO postgres; + +-- +-- Name: COLUMN gateway_endpoints.created_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gateway_endpoints.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN gateway_endpoints.detail; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gateway_endpoints.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN gateway_endpoints.id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gateway_endpoints.id IS 'ID of the record'; + + +-- +-- Name: COLUMN gateway_endpoints.updated_at; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gateway_endpoints.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: gcm_accounts; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal.gcm_accounts ( + id uuid NOT NULL, + obfuscated_id text, + entitlement_id uuid, + approved boolean DEFAULT false +); + + +ALTER TABLE internal.gcm_accounts OWNER TO postgres; + +-- +-- Name: COLUMN gcm_accounts.id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gcm_accounts.id IS 'Google marketplace user ID, received in the first ACCOUNT_ACTIVE pub/sub event and as the subject of the JWT token during signup'; + + +-- +-- Name: COLUMN gcm_accounts.obfuscated_id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gcm_accounts.obfuscated_id IS 'Google GAIA ID, received in JWT during sign-up, can be used to sign the user in using OAuth2'; + + +-- +-- Name: COLUMN gcm_accounts.approved; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.gcm_accounts.approved IS 'Has the account been approved with Google'; + + +-- +-- Name: illegal_tenant_names; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal.illegal_tenant_names ( + name public.catalog_tenant NOT NULL +); + + +ALTER TABLE internal.illegal_tenant_names OWNER TO postgres; + +-- +-- Name: TABLE illegal_tenant_names; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON TABLE internal.illegal_tenant_names IS 'Illegal tenant names which are not allowed to be provisioned by users'; + + +-- +-- Name: manual_bills; Type: TABLE; Schema: internal; Owner: postgres +-- + +CREATE TABLE internal.manual_bills ( + tenant public.catalog_tenant NOT NULL, + usd_cents integer NOT NULL, + description text NOT NULL, + date_start date NOT NULL, + date_end date NOT NULL, + CONSTRAINT dates_make_sense CHECK ((date_start < date_end)) +); + + +ALTER TABLE internal.manual_bills OWNER TO postgres; + +-- +-- Name: TABLE manual_bills; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON TABLE internal.manual_bills IS 'Manually entered bills that span an arbitrary date range'; + + +-- +-- Name: catalog_stats_daily; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.catalog_stats_daily ( + catalog_name public.catalog_name NOT NULL, + grain text NOT NULL, + ts timestamp with time zone NOT NULL, + bytes_written_by_me bigint DEFAULT 0 NOT NULL, + docs_written_by_me bigint DEFAULT 0 NOT NULL, + bytes_read_by_me bigint DEFAULT 0 NOT NULL, + docs_read_by_me bigint DEFAULT 0 NOT NULL, + bytes_written_to_me bigint DEFAULT 0 NOT NULL, + docs_written_to_me bigint DEFAULT 0 NOT NULL, + bytes_read_from_me bigint DEFAULT 0 NOT NULL, + docs_read_from_me bigint DEFAULT 0 NOT NULL, + usage_seconds integer DEFAULT 0 NOT NULL, + warnings integer DEFAULT 0 NOT NULL, + errors integer DEFAULT 0 NOT NULL, + failures integer DEFAULT 0 NOT NULL, + flow_document json NOT NULL +); + + +ALTER TABLE public.catalog_stats_daily OWNER TO postgres; + +-- +-- Name: catalog_stats_monthly; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.catalog_stats_monthly ( + catalog_name public.catalog_name NOT NULL, + grain text NOT NULL, + ts timestamp with time zone NOT NULL, + bytes_written_by_me bigint DEFAULT 0 NOT NULL, + docs_written_by_me bigint DEFAULT 0 NOT NULL, + bytes_read_by_me bigint DEFAULT 0 NOT NULL, + docs_read_by_me bigint DEFAULT 0 NOT NULL, + bytes_written_to_me bigint DEFAULT 0 NOT NULL, + docs_written_to_me bigint DEFAULT 0 NOT NULL, + bytes_read_from_me bigint DEFAULT 0 NOT NULL, + docs_read_from_me bigint DEFAULT 0 NOT NULL, + usage_seconds integer DEFAULT 0 NOT NULL, + warnings integer DEFAULT 0 NOT NULL, + errors integer DEFAULT 0 NOT NULL, + failures integer DEFAULT 0 NOT NULL, + flow_document json NOT NULL +); + + +ALTER TABLE public.catalog_stats_monthly OWNER TO postgres; + +-- +-- Name: new_free_trial_tenants; Type: VIEW; Schema: internal; Owner: postgres +-- + +CREATE VIEW internal.new_free_trial_tenants AS + WITH hours_by_day AS ( + SELECT tenants_1.tenant, + catalog_stats_daily.ts, + sum(((catalog_stats_daily.usage_seconds)::numeric / (60.0 * (60)::numeric))) AS daily_usage_hours + FROM (public.catalog_stats_daily + JOIN public.tenants tenants_1 ON (((catalog_stats_daily.catalog_name)::text ^@ (tenants_1.tenant)::text))) + WHERE (tenants_1.trial_start IS NULL) + GROUP BY tenants_1.tenant, catalog_stats_daily.ts + HAVING (sum(((catalog_stats_daily.usage_seconds)::numeric / (60.0 * (60)::numeric))) > (((2 * 24))::numeric * 1.1)) + ), hours_by_month AS ( + SELECT tenants_1.tenant, + catalog_stats_monthly.ts, + sum(((catalog_stats_monthly.usage_seconds)::numeric / (60.0 * (60)::numeric))) AS monthly_usage_hours + FROM (public.catalog_stats_monthly + JOIN public.tenants tenants_1 ON (((catalog_stats_monthly.catalog_name)::text ^@ (tenants_1.tenant)::text))) + WHERE (tenants_1.trial_start IS NULL) + GROUP BY tenants_1.tenant, catalog_stats_monthly.ts + HAVING (sum(((catalog_stats_monthly.usage_seconds)::numeric / (60.0 * (60)::numeric))) > ((((24 * 31) * 2))::numeric * 1.1)) + ), gbs_by_month AS ( + SELECT tenants_1.tenant, + catalog_stats_monthly.ts, + ceil(sum((((catalog_stats_monthly.bytes_written_by_me + catalog_stats_monthly.bytes_read_by_me))::numeric / (10.0 ^ 9.0)))) AS monthly_usage_gbs + FROM (public.catalog_stats_monthly + JOIN public.tenants tenants_1 ON (((catalog_stats_monthly.catalog_name)::text ^@ (tenants_1.tenant)::text))) + WHERE (tenants_1.trial_start IS NULL) + GROUP BY tenants_1.tenant, catalog_stats_monthly.ts + HAVING (ceil(sum((((catalog_stats_monthly.bytes_written_by_me + catalog_stats_monthly.bytes_read_by_me))::numeric / (10.0 ^ 9.0)))) > (10)::numeric) + ) + SELECT tenants.tenant, + max(hours_by_day.daily_usage_hours) AS max_daily_usage_hours, + max(hours_by_month.monthly_usage_hours) AS max_monthly_usage_hours, + max(gbs_by_month.monthly_usage_gbs) AS max_monthly_gb, + count(DISTINCT live_specs.id) FILTER (WHERE (live_specs.spec_type = 'capture'::public.catalog_spec_type)) AS today_captures, + count(DISTINCT live_specs.id) FILTER (WHERE (live_specs.spec_type = 'materialization'::public.catalog_spec_type)) AS today_materializations + FROM ((((public.tenants + LEFT JOIN hours_by_day ON (((hours_by_day.tenant)::text = (tenants.tenant)::text))) + LEFT JOIN hours_by_month ON (((hours_by_month.tenant)::text = (tenants.tenant)::text))) + LEFT JOIN gbs_by_month ON (((gbs_by_month.tenant)::text = (tenants.tenant)::text))) + JOIN public.live_specs ON ((((split_part((live_specs.catalog_name)::text, '/'::text, 1) || '/'::text) = (tenants.tenant)::text) AND (((live_specs.spec #>> '{shards,disable}'::text[]))::boolean IS NOT TRUE)))) + WHERE (tenants.trial_start IS NULL) + GROUP BY tenants.tenant + HAVING ((count(hours_by_month.*) > 0) OR (count(hours_by_day.*) > 0) OR (count(gbs_by_month.*) > 0)); + + +ALTER VIEW internal.new_free_trial_tenants OWNER TO postgres; + +-- +-- Name: next_auto_discovers; Type: VIEW; Schema: internal; Owner: postgres +-- + +CREATE VIEW internal.next_auto_discovers AS +SELECT + NULL::public.flowid AS capture_id, + NULL::public.catalog_name AS capture_name, + NULL::json AS endpoint_json, + NULL::boolean AS add_new_bindings, + NULL::boolean AS evolve_incompatible_collections, + NULL::public.flowid AS connector_tags_id, + NULL::interval AS overdue_interval; + + +ALTER VIEW internal.next_auto_discovers OWNER TO postgres; + +-- +-- Name: VIEW next_auto_discovers; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON VIEW internal.next_auto_discovers IS 'A view of captures that are due for an automatic discovery operation. +This is determined by comparing the time of the last discover operation +against the curent time'; + + +-- +-- Name: COLUMN next_auto_discovers.capture_id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.next_auto_discovers.capture_id IS 'Primary key of the live_specs row for the capture'; + + +-- +-- Name: COLUMN next_auto_discovers.capture_name; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.next_auto_discovers.capture_name IS 'Catalog name of the capture'; + + +-- +-- Name: COLUMN next_auto_discovers.endpoint_json; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.next_auto_discovers.endpoint_json IS 'The endpoint configuration of the capture, to use with the next discover.'; + + +-- +-- Name: COLUMN next_auto_discovers.add_new_bindings; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.next_auto_discovers.add_new_bindings IS 'Whether to add newly discovered bindings. If false, then it will only update existing bindings.'; + + +-- +-- Name: COLUMN next_auto_discovers.evolve_incompatible_collections; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.next_auto_discovers.evolve_incompatible_collections IS 'Whether to automatically perform schema evolution in the event that the newly discovered collections are incompatble.'; + + +-- +-- Name: COLUMN next_auto_discovers.connector_tags_id; Type: COMMENT; Schema: internal; Owner: postgres +-- + +COMMENT ON COLUMN internal.next_auto_discovers.connector_tags_id IS 'The id of the connector_tags row that corresponds to the image used by this capture.'; + + +-- +-- Name: shard_0_id_sequence; Type: SEQUENCE; Schema: internal; Owner: postgres +-- + +CREATE SEQUENCE internal.shard_0_id_sequence + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +ALTER SEQUENCE internal.shard_0_id_sequence OWNER TO postgres; + +-- +-- Name: user_profiles; Type: VIEW; Schema: internal; Owner: postgres +-- + +CREATE VIEW internal.user_profiles AS + SELECT users.id AS user_id, + users.email, + COALESCE((users.raw_user_meta_data ->> 'full_name'::text), (users.raw_user_meta_data ->> 'name'::text)) AS full_name, + COALESCE((users.raw_user_meta_data ->> 'picture'::text), (users.raw_user_meta_data ->> 'avatar_url'::text)) AS avatar_url + FROM auth.users; + + +ALTER VIEW internal.user_profiles OWNER TO postgres; + +-- +-- Name: alert_all; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.alert_all AS + SELECT alert_free_trial.alert_type, + alert_free_trial.catalog_name, + alert_free_trial.arguments, + alert_free_trial.firing + FROM internal.alert_free_trial +UNION ALL + SELECT alert_free_trial_ending.alert_type, + alert_free_trial_ending.catalog_name, + alert_free_trial_ending.arguments, + alert_free_trial_ending.firing + FROM internal.alert_free_trial_ending +UNION ALL + SELECT alert_free_trial_stalled.alert_type, + alert_free_trial_stalled.catalog_name, + alert_free_trial_stalled.arguments, + alert_free_trial_stalled.firing + FROM internal.alert_free_trial_stalled +UNION ALL + SELECT alert_missing_payment_method.alert_type, + alert_missing_payment_method.catalog_name, + alert_missing_payment_method.arguments, + alert_missing_payment_method.firing + FROM internal.alert_missing_payment_method +UNION ALL + SELECT alert_data_movement_stalled.alert_type, + alert_data_movement_stalled.catalog_name, + alert_data_movement_stalled.arguments, + alert_data_movement_stalled.firing + FROM internal.alert_data_movement_stalled; + + +ALTER VIEW public.alert_all OWNER TO postgres; + +-- +-- Name: alert_history; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.alert_history ( + alert_type public.alert_type NOT NULL, + catalog_name public.catalog_name NOT NULL, + fired_at timestamp with time zone NOT NULL, + resolved_at timestamp with time zone, + arguments json NOT NULL, + resolved_arguments jsonb +); + + +ALTER TABLE public.alert_history OWNER TO postgres; + +-- +-- Name: role_grants; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.role_grants ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + subject_role public.catalog_prefix NOT NULL, + object_role public.catalog_prefix NOT NULL, + capability public.grant_capability NOT NULL, + CONSTRAINT valid_capability CHECK ((capability = ANY (ARRAY['read'::public.grant_capability, 'write'::public.grant_capability, 'admin'::public.grant_capability]))) +); + + +ALTER TABLE public.role_grants OWNER TO postgres; + +-- +-- Name: TABLE role_grants; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.role_grants IS 'Roles and capabilities that roles have been granted to other roles'; + + +-- +-- Name: COLUMN role_grants.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.role_grants.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN role_grants.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.role_grants.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN role_grants.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.role_grants.id IS 'ID of the record'; + + +-- +-- Name: COLUMN role_grants.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.role_grants.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN role_grants.subject_role; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.role_grants.subject_role IS 'Role which has been granted a capability to another role'; + + +-- +-- Name: COLUMN role_grants.object_role; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.role_grants.object_role IS 'Role to which a capability has been granted'; + + +-- +-- Name: COLUMN role_grants.capability; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.role_grants.capability IS 'Capability which is granted to the subject role'; + + +-- +-- Name: user_grants; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.user_grants ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + user_id uuid NOT NULL, + object_role public.catalog_prefix NOT NULL, + capability public.grant_capability NOT NULL, + CONSTRAINT valid_capability CHECK ((capability = ANY (ARRAY['read'::public.grant_capability, 'write'::public.grant_capability, 'admin'::public.grant_capability]))) +); + + +ALTER TABLE public.user_grants OWNER TO postgres; + +-- +-- Name: TABLE user_grants; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.user_grants IS 'Roles and capabilities that the user has been granted'; + + +-- +-- Name: COLUMN user_grants.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.user_grants.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN user_grants.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.user_grants.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN user_grants.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.user_grants.id IS 'ID of the record'; + + +-- +-- Name: COLUMN user_grants.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.user_grants.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN user_grants.user_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.user_grants.user_id IS 'User who has been granted a role'; + + +-- +-- Name: COLUMN user_grants.object_role; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.user_grants.object_role IS 'Role which is granted to the user'; + + +-- +-- Name: COLUMN user_grants.capability; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.user_grants.capability IS 'Capability which is granted to the user'; + + +-- +-- Name: combined_grants_ext; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.combined_grants_ext AS + WITH admin_roles AS ( + SELECT auth_roles.role_prefix + FROM public.auth_roles('admin'::public.grant_capability) auth_roles(role_prefix, capability) + ), user_id(id) AS ( + SELECT auth.uid() AS uid + ) + SELECT g.capability, + g.created_at, + g.detail, + g.id, + g.object_role, + g.updated_at, + g.subject_role, + NULL::text AS user_avatar_url, + NULL::character varying AS user_email, + NULL::text AS user_full_name, + NULL::uuid AS user_id + FROM public.role_grants g + WHERE ((g.id)::macaddr8 IN ( SELECT g_1.id + FROM admin_roles r, + public.role_grants g_1 + WHERE (((g_1.subject_role)::text ^@ (r.role_prefix)::text) OR ((g_1.object_role)::text ^@ (r.role_prefix)::text)))) +UNION ALL + SELECT g.capability, + g.created_at, + g.detail, + g.id, + g.object_role, + g.updated_at, + NULL::text AS subject_role, + u.avatar_url AS user_avatar_url, + u.email AS user_email, + u.full_name AS user_full_name, + g.user_id + FROM (public.user_grants g + LEFT JOIN internal.user_profiles u ON ((u.user_id = g.user_id))) + WHERE ((g.id)::macaddr8 IN ( SELECT g_1.id + FROM admin_roles r, + public.user_grants g_1 + WHERE ((g_1.user_id = ( SELECT user_id.id + FROM user_id)) OR ((g_1.object_role)::text ^@ (r.role_prefix)::text)))); + + +ALTER VIEW public.combined_grants_ext OWNER TO postgres; + +-- +-- Name: VIEW combined_grants_ext; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON VIEW public.combined_grants_ext IS 'Combined view of `role_grants` and `user_grants` extended with user metadata'; + + +-- +-- Name: connector_tags; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.connector_tags ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + job_status public.jsonb_obj DEFAULT '{"type": "queued"}'::jsonb NOT NULL, + logs_token uuid DEFAULT gen_random_uuid() NOT NULL, + connector_id public.flowid NOT NULL, + documentation_url text, + endpoint_spec_schema public.json_obj, + image_tag text NOT NULL, + protocol text, + resource_spec_schema public.json_obj, + auto_discover_interval interval DEFAULT '02:00:00'::interval NOT NULL, + resource_path_pointers public.json_pointer[], + background boolean DEFAULT false NOT NULL, + default_capture_interval interval, + disable_backfill boolean DEFAULT false NOT NULL, + CONSTRAINT connector_tags_resource_path_pointers_check CHECK ((array_length(resource_path_pointers, 1) > 0)), + CONSTRAINT "image_tag must start with : (as in :latest) or @sha256:" CHECK (((image_tag ~~ ':%'::text) OR (image_tag ~~ '@sha256:'::text))) +); + + +ALTER TABLE public.connector_tags OWNER TO postgres; + +-- +-- Name: TABLE connector_tags; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.connector_tags IS ' +Available image tags (versions) of connectors. +Tags are _typically_ immutable versions, +but it''s possible to update the image digest backing a tag, +which is arguably a different version. +'; + + +-- +-- Name: COLUMN connector_tags.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN connector_tags.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN connector_tags.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.id IS 'ID of the record'; + + +-- +-- Name: COLUMN connector_tags.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN connector_tags.job_status; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.job_status IS 'Server-side job executation status of the record'; + + +-- +-- Name: COLUMN connector_tags.logs_token; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.logs_token IS 'Bearer token for accessing logs of the server-side operation'; + + +-- +-- Name: COLUMN connector_tags.connector_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.connector_id IS 'Connector which this record is a tag of'; + + +-- +-- Name: COLUMN connector_tags.documentation_url; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.documentation_url IS 'Documentation URL of the tagged connector'; + + +-- +-- Name: COLUMN connector_tags.endpoint_spec_schema; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.endpoint_spec_schema IS 'Endpoint specification JSON-Schema of the tagged connector'; + + +-- +-- Name: COLUMN connector_tags.image_tag; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.image_tag IS 'Image tag, in either ":v1.2.3", ":latest", or "@sha256:" form'; + + +-- +-- Name: COLUMN connector_tags.protocol; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.protocol IS 'Protocol of the connector'; + + +-- +-- Name: COLUMN connector_tags.resource_spec_schema; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.resource_spec_schema IS 'Resource specification JSON-Schema of the tagged connector'; + + +-- +-- Name: COLUMN connector_tags.auto_discover_interval; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.auto_discover_interval IS 'Frequency at which to perform automatic discovery operations for captures, when autoDiscover is enabled'; + + +-- +-- Name: COLUMN connector_tags.resource_path_pointers; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.resource_path_pointers IS 'The resource_path that was returned from the connector spec response'; + + +-- +-- Name: COLUMN connector_tags.background; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.background IS 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; + + +-- +-- Name: COLUMN connector_tags.default_capture_interval; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.default_capture_interval IS 'The default value for the interval property for a Capture. This is normally used for non-streaming connectors'; + + +-- +-- Name: COLUMN connector_tags.disable_backfill; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connector_tags.disable_backfill IS 'Controls if the UI will hide the backfill button for a connector'; + + +-- +-- Name: connectors; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.connectors ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + external_url text NOT NULL, + image_name text NOT NULL, + oauth2_client_id text, + oauth2_client_secret text, + oauth2_spec public.jsonb_obj, + oauth2_injected_values public.jsonb_obj, + short_description public.jsonb_internationalized_value, + title public.jsonb_internationalized_value, + logo_url public.jsonb_internationalized_value, + recommended boolean NOT NULL, + long_description public.jsonb_internationalized_value, + CONSTRAINT "image_name must be a container image without a tag" CHECK ((image_name ~ '^(?:.+/)?([^:]+)$'::text)) +); + + +ALTER TABLE public.connectors OWNER TO postgres; + +-- +-- Name: TABLE connectors; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.connectors IS ' +Connectors are Docker / OCI images which implement a standard protocol, +and allow Flow to interface with an external system for the capture +or materialization of data. +'; + + +-- +-- Name: COLUMN connectors.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN connectors.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN connectors.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.id IS 'ID of the record'; + + +-- +-- Name: COLUMN connectors.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN connectors.external_url; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.external_url IS 'External URL which provides more information about the endpoint'; + + +-- +-- Name: COLUMN connectors.image_name; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.image_name IS 'Name of the connector''s container (Docker) image, for example "ghcr.io/estuary/source-postgres"'; + + +-- +-- Name: COLUMN connectors.oauth2_client_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.oauth2_client_id IS 'oauth client id'; + + +-- +-- Name: COLUMN connectors.oauth2_client_secret; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.oauth2_client_secret IS 'oauth client secret'; + + +-- +-- Name: COLUMN connectors.oauth2_spec; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.oauth2_spec IS 'OAuth2 specification of the connector'; + + +-- +-- Name: COLUMN connectors.oauth2_injected_values; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.oauth2_injected_values IS 'oauth additional injected values, these values will be made available in the credentials key of the connector, as well as when rendering oauth2_spec templates'; + + +-- +-- Name: COLUMN connectors.short_description; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.short_description IS 'A short description of this connector, at most a few sentences. Represented as a json object with IETF language tags as keys (https://en.wikipedia.org/wiki/IETF_language_tag), and the description string as values'; + + +-- +-- Name: COLUMN connectors.title; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.title IS 'The title of this connector. Represented as a json object with IETF language tags as keys (https://en.wikipedia.org/wiki/IETF_language_tag), and the title string as values'; + + +-- +-- Name: COLUMN connectors.logo_url; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.logo_url IS 'The url for this connector''s logo image. Represented as a json object with IETF language tags as keys (https://en.wikipedia.org/wiki/IETF_language_tag), and urls as values'; + + +-- +-- Name: COLUMN connectors.long_description; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.connectors.long_description IS 'A longform description of this connector. Represented as a json object with IETF language tags as keys (https://en.wikipedia.org/wiki/IETF_language_tag), and the description string as values'; + + +-- +-- Name: controller_jobs; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.controller_jobs ( + live_spec_id public.flowid NOT NULL, + controller_version integer DEFAULT 0 NOT NULL, + status json DEFAULT '{}'::json NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + logs_token uuid DEFAULT gen_random_uuid() NOT NULL, + failures integer DEFAULT 0 NOT NULL, + error text +); + + +ALTER TABLE public.controller_jobs OWNER TO postgres; + +-- +-- Name: TABLE controller_jobs; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.controller_jobs IS 'Controller jobs reflect the state of the automated background processes that + manage live specs. Controllers are responsible for things like updating + inferred schemas, activating and deleting shard and journal specs in the data + plane, and any other type of background automation.'; + + +-- +-- Name: COLUMN controller_jobs.live_spec_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.controller_jobs.live_spec_id IS 'The id of the live_specs row that this contoller job pertains to.'; + + +-- +-- Name: COLUMN controller_jobs.controller_version; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.controller_jobs.controller_version IS 'The version of the controller that last ran. This number only increases + monotonically, and only when a breaking change to the controller status + is released. Every controller_job starts out with a controller_version of 0, + and will subsequently be upgraded to the current controller version by the + first controller run.'; + + +-- +-- Name: COLUMN controller_jobs.status; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.controller_jobs.status IS 'Contains type-specific information about the controller and the actions it + has performed.'; + + +-- +-- Name: COLUMN controller_jobs.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.controller_jobs.updated_at IS 'Timestamp of the last update to the controller_job.'; + + +-- +-- Name: COLUMN controller_jobs.logs_token; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.controller_jobs.logs_token IS 'Token that can be used to query logs from controller runs from + internal.log_lines.'; + + +-- +-- Name: COLUMN controller_jobs.failures; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.controller_jobs.failures IS 'Count of consecutive failures of this controller. This is reset to 0 upon + any successful controller run. If failures is > 0, then error will be set'; + + +-- +-- Name: COLUMN controller_jobs.error; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.controller_jobs.error IS 'The error from the most recent controller run, which will be null if the + run was successful. If this is set, then failures will be > 0'; + + +-- +-- Name: data_planes; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.data_planes ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + data_plane_name public.catalog_name NOT NULL, + data_plane_fqdn text NOT NULL, + ops_logs_name public.catalog_name NOT NULL, + ops_stats_name public.catalog_name NOT NULL, + ops_l1_inferred_name public.catalog_name NOT NULL, + ops_l1_stats_name public.catalog_name NOT NULL, + ops_l2_inferred_transform text NOT NULL, + ops_l2_stats_transform text NOT NULL, + broker_address text NOT NULL, + reactor_address text NOT NULL, + config json DEFAULT '{}'::json NOT NULL, + status json DEFAULT '{}'::json NOT NULL, + logs_token uuid DEFAULT gen_random_uuid() NOT NULL, + hmac_keys text[] NOT NULL, + aws_iam_user_arn text, + cidr_blocks cidr[] DEFAULT '{}'::cidr[] NOT NULL, + enable_l2 boolean NOT NULL, + gcp_service_account_email text, + ssh_private_key text +); + + +ALTER TABLE public.data_planes OWNER TO postgres; + +-- +-- Name: COLUMN data_planes.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.data_planes.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN data_planes.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.data_planes.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN data_planes.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.data_planes.id IS 'ID of the record'; + + +-- +-- Name: COLUMN data_planes.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.data_planes.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: discovers; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.discovers ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + job_status public.jsonb_obj DEFAULT '{"type": "queued"}'::jsonb NOT NULL, + logs_token uuid DEFAULT gen_random_uuid() NOT NULL, + capture_name public.catalog_name NOT NULL, + connector_tag_id public.flowid NOT NULL, + draft_id public.flowid NOT NULL, + endpoint_config public.json_obj NOT NULL, + update_only boolean DEFAULT false NOT NULL, + auto_publish boolean DEFAULT false NOT NULL, + auto_evolve boolean DEFAULT false NOT NULL, + background boolean DEFAULT false NOT NULL, + data_plane_name text DEFAULT 'ops/dp/public/gcp-us-central1-c1'::text NOT NULL +); + + +ALTER TABLE public.discovers OWNER TO postgres; + +-- +-- Name: TABLE discovers; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.discovers IS 'User-initiated connector discovery operations'; + + +-- +-- Name: COLUMN discovers.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN discovers.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN discovers.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.id IS 'ID of the record'; + + +-- +-- Name: COLUMN discovers.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN discovers.job_status; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.job_status IS 'Server-side job executation status of the record'; + + +-- +-- Name: COLUMN discovers.logs_token; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.logs_token IS 'Bearer token for accessing logs of the server-side operation'; + + +-- +-- Name: COLUMN discovers.capture_name; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.capture_name IS 'Intended name of the capture produced by this discover'; + + +-- +-- Name: COLUMN discovers.connector_tag_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.connector_tag_id IS 'Tagged connector which is used for discovery'; + + +-- +-- Name: COLUMN discovers.draft_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.draft_id IS 'Draft to be populated by this discovery operation'; + + +-- +-- Name: COLUMN discovers.endpoint_config; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.endpoint_config IS 'Endpoint configuration of the connector. May be protected by sops'; + + +-- +-- Name: COLUMN discovers.update_only; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.update_only IS ' +If true, this operation will draft updates to existing bindings and their +target collections but will not add new bindings or collections.'; + + +-- +-- Name: COLUMN discovers.auto_publish; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.auto_publish IS 'whether to automatically publish the results of the discover, if successful'; + + +-- +-- Name: COLUMN discovers.auto_evolve; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.auto_evolve IS 'whether to automatically create an evolutions job if the automatic publication +fails due to incompatible collection schemas. This determines the value of `auto_evolve` +in the publications table when inserting a new row as a result of this discover.'; + + +-- +-- Name: COLUMN discovers.background; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.discovers.background IS 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; + + +-- +-- Name: draft_errors; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.draft_errors ( + draft_id public.flowid NOT NULL, + scope text NOT NULL, + detail text NOT NULL +); + + +ALTER TABLE public.draft_errors OWNER TO postgres; + +-- +-- Name: TABLE draft_errors; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.draft_errors IS 'Errors found while validating, testing or publishing a user draft'; + + +-- +-- Name: COLUMN draft_errors.draft_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_errors.draft_id IS 'Draft which produed this error'; + + +-- +-- Name: COLUMN draft_errors.scope; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_errors.scope IS 'Location scope of the error within the draft'; + + +-- +-- Name: COLUMN draft_errors.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_errors.detail IS 'Description of the error'; + + +-- +-- Name: draft_specs; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.draft_specs ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + draft_id public.flowid NOT NULL, + catalog_name public.catalog_name NOT NULL, + expect_pub_id public.flowid DEFAULT NULL::macaddr8, + spec json, + spec_type public.catalog_spec_type, + built_spec json, + validated json +); + + +ALTER TABLE public.draft_specs OWNER TO postgres; + +-- +-- Name: TABLE draft_specs; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.draft_specs IS 'Proposed catalog specifications of a draft'; + + +-- +-- Name: COLUMN draft_specs.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN draft_specs.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN draft_specs.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.id IS 'ID of the record'; + + +-- +-- Name: COLUMN draft_specs.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN draft_specs.draft_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.draft_id IS 'Draft which this specification belongs to'; + + +-- +-- Name: COLUMN draft_specs.catalog_name; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.catalog_name IS 'Catalog name of this specification'; + + +-- +-- Name: COLUMN draft_specs.expect_pub_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.expect_pub_id IS ' +Draft specifications may be drawn from a current live specification, +and in this case it''s recommended that expect_pub_id is also set to the +last_pub_id of that inititializing live specification. + +Or if there isn''t expected to be a live specification then +expect_pub_id can be the set to an explicit value of ''00:00:00:00:00:00:00:00'' +to represent that no live specification is expected to exist. + +Then when this draft is published, the publication will fail if the now-current +live specification has a different last_pub_id. This prevents inadvertent errors +where two users attempt to modify or create a catalog specification at the same time, +as the second user publication will fail rather than silently overwriting changes +made by the first user. + +When NULL, expect_pub_id has no effect. +'; + + +-- +-- Name: COLUMN draft_specs.spec; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.spec IS ' +Spec is a serialized catalog specification. Its schema depends on its spec_type: +either CollectionDef, CaptureDef, MaterializationDef, DerivationDef, +or an array of TestStep from the Flow catalog schema. + +It may also be NULL, in which case `spec_type` must also be NULL +and the specification will be deleted when this draft is published. +'; + + +-- +-- Name: COLUMN draft_specs.spec_type; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.spec_type IS 'Type of this draft catalog specification'; + + +-- +-- Name: COLUMN draft_specs.built_spec; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.built_spec IS 'Built specification for this catalog'; + + +-- +-- Name: COLUMN draft_specs.validated; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.draft_specs.validated IS 'Serialized response from the connector Validate RPC as populated by a dry run of this draft specification'; + + +-- +-- Name: drafts; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.drafts ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + user_id uuid DEFAULT auth.uid() NOT NULL +); + + +ALTER TABLE public.drafts OWNER TO postgres; + +-- +-- Name: TABLE drafts; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.drafts IS 'Draft change-sets of Flow catalog specifications'; + + +-- +-- Name: COLUMN drafts.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.drafts.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN drafts.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.drafts.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN drafts.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.drafts.id IS 'ID of the record'; + + +-- +-- Name: COLUMN drafts.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.drafts.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN drafts.user_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.drafts.user_id IS 'User who owns this draft'; + + +-- +-- Name: inferred_schemas; Type: TABLE; Schema: public; Owner: stats_loader +-- + +CREATE TABLE public.inferred_schemas ( + collection_name public.catalog_name NOT NULL, + schema json NOT NULL, + flow_document json NOT NULL, + md5 text GENERATED ALWAYS AS (md5(TRIM(BOTH FROM (schema)::text))) STORED +); + + +ALTER TABLE public.inferred_schemas OWNER TO stats_loader; + +-- +-- Name: TABLE inferred_schemas; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON TABLE public.inferred_schemas IS 'Generated for materialization ops.us-central1.v1/stats-view of collection ops.us-central1.v1/inferred-schemas/L2'; + + +-- +-- Name: COLUMN inferred_schemas.collection_name; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.inferred_schemas.collection_name IS 'The name of the collection that this schema was inferred for +auto-generated projection of JSON at: /collection_name with inferred types: [string]'; + + +-- +-- Name: COLUMN inferred_schemas.schema; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.inferred_schemas.schema IS 'The inferred schema +auto-generated projection of JSON at: /schema with inferred types: [object]'; + + +-- +-- Name: COLUMN inferred_schemas.flow_document; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.inferred_schemas.flow_document IS 'auto-generated projection of JSON at: with inferred types: [object]'; + + +-- +-- Name: COLUMN inferred_schemas.md5; Type: COMMENT; Schema: public; Owner: stats_loader +-- + +COMMENT ON COLUMN public.inferred_schemas.md5 IS 'hash of the inferred schema json, which is used to identify changes'; + + +-- +-- Name: publication_specs; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.publication_specs ( + live_spec_id public.flowid NOT NULL, + pub_id public.flowid NOT NULL, + detail text, + published_at timestamp with time zone DEFAULT now() NOT NULL, + spec json, + spec_type public.catalog_spec_type, + user_id uuid DEFAULT auth.uid() NOT NULL +); + + +ALTER TABLE public.publication_specs OWNER TO postgres; + +-- +-- Name: TABLE publication_specs; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.publication_specs IS ' +publication_specs details the publication history of the `live_specs` catalog. +Each change to a live specification is recorded into `publication_specs`. +'; + + +-- +-- Name: COLUMN publication_specs.live_spec_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publication_specs.live_spec_id IS 'Live catalog specification which was published'; + + +-- +-- Name: COLUMN publication_specs.pub_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publication_specs.pub_id IS 'Publication ID which published to the catalog specification'; + + +-- +-- Name: COLUMN publication_specs.spec; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publication_specs.spec IS ' +Catalog specification which was published by this publication, +or NULL if this was a deletion. +'; + + +-- +-- Name: COLUMN publication_specs.spec_type; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publication_specs.spec_type IS 'Type of the published catalog specification, or NULL if this was a deletion'; + + +-- +-- Name: COLUMN publication_specs.user_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publication_specs.user_id IS 'User who performed this publication.'; + + +-- +-- Name: live_specs_ext; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.live_specs_ext AS + WITH authorized_specs AS ( + SELECT l_1.id + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability), + public.live_specs l_1 + WHERE ((l_1.catalog_name)::text ^@ (r.role_prefix)::text) + ) + SELECT l.created_at, + l.detail, + l.id, + l.updated_at, + l.catalog_name, + l.connector_image_name, + l.connector_image_tag, + l.last_pub_id, + l.reads_from, + l.spec, + l.spec_type, + l.writes_to, + l.last_build_id, + l.md5, + l.built_spec, + l.inferred_schema_md5, + l.controller_next_run, + c.external_url AS connector_external_url, + c.id AS connector_id, + c.title AS connector_title, + c.short_description AS connector_short_description, + c.logo_url AS connector_logo_url, + c.recommended AS connector_recommended, + t.id AS connector_tag_id, + t.documentation_url AS connector_tag_documentation_url, + p.detail AS last_pub_detail, + p.user_id AS last_pub_user_id, + u.avatar_url AS last_pub_user_avatar_url, + u.email AS last_pub_user_email, + u.full_name AS last_pub_user_full_name, + l.journal_template_name, + l.shard_template_id, + l.data_plane_id, + d.broker_address, + d.data_plane_name, + d.reactor_address + FROM (((((public.live_specs l + LEFT JOIN public.publication_specs p ON ((((l.id)::macaddr8 = (p.live_spec_id)::macaddr8) AND ((l.last_pub_id)::macaddr8 = (p.pub_id)::macaddr8)))) + LEFT JOIN public.connectors c ON ((c.image_name = l.connector_image_name))) + LEFT JOIN public.connector_tags t ON ((((c.id)::macaddr8 = (t.connector_id)::macaddr8) AND (l.connector_image_tag = t.image_tag)))) + LEFT JOIN internal.user_profiles u ON ((u.user_id = p.user_id))) + LEFT JOIN public.data_planes d ON (((d.id)::macaddr8 = (l.data_plane_id)::macaddr8))) + WHERE ((EXISTS ( SELECT 1 + FROM pg_roles + WHERE ((pg_roles.rolname = CURRENT_ROLE) AND (pg_roles.rolbypassrls = true)))) OR ((l.id)::macaddr8 IN ( SELECT authorized_specs.id + FROM authorized_specs))); + + +ALTER VIEW public.live_specs_ext OWNER TO postgres; + +-- +-- Name: VIEW live_specs_ext; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON VIEW public.live_specs_ext IS 'View of `live_specs` extended with metadata of its last publication'; + + +-- +-- Name: draft_specs_ext; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.draft_specs_ext AS + WITH authorized_drafts AS ( + SELECT drafts.id + FROM public.drafts + WHERE (drafts.user_id = ( SELECT auth.uid() AS uid)) + ) + SELECT d.created_at, + d.detail, + d.id, + d.updated_at, + d.draft_id, + d.catalog_name, + d.expect_pub_id, + d.spec, + d.spec_type, + d.built_spec, + d.validated, + l.last_pub_detail, + l.last_pub_id, + l.last_pub_user_id, + l.last_pub_user_avatar_url, + l.last_pub_user_email, + l.last_pub_user_full_name, + l.spec AS live_spec, + l.spec_type AS live_spec_type, + s.md5 AS inferred_schema_md5, + l.inferred_schema_md5 AS live_inferred_schema_md5, + l.md5 AS live_spec_md5, + md5(TRIM(BOTH FROM (d.spec)::text)) AS draft_spec_md5 + FROM ((public.draft_specs d + LEFT JOIN public.live_specs_ext l ON (((d.catalog_name)::text = (l.catalog_name)::text))) + LEFT JOIN public.inferred_schemas s ON (((s.collection_name)::text = (l.catalog_name)::text))) + WHERE ((EXISTS ( SELECT 1 + FROM pg_roles + WHERE ((pg_roles.rolname = CURRENT_ROLE) AND (pg_roles.rolbypassrls = true)))) OR ((d.draft_id)::macaddr8 IN ( SELECT authorized_drafts.id + FROM authorized_drafts))); + + +ALTER VIEW public.draft_specs_ext OWNER TO postgres; + +-- +-- Name: VIEW draft_specs_ext; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON VIEW public.draft_specs_ext IS 'View of `draft_specs` extended with metadata of its live specification'; + + +-- +-- Name: drafts_ext; Type: VIEW; Schema: public; Owner: authenticated +-- + +CREATE VIEW public.drafts_ext AS + SELECT d.created_at, + d.detail, + d.id, + d.updated_at, + d.user_id, + s.num_specs + FROM public.drafts d, + LATERAL ( SELECT count(*) AS num_specs + FROM public.draft_specs + WHERE ((draft_specs.draft_id)::macaddr8 = (d.id)::macaddr8)) s; + + +ALTER VIEW public.drafts_ext OWNER TO authenticated; + +-- +-- Name: VIEW drafts_ext; Type: COMMENT; Schema: public; Owner: authenticated +-- + +COMMENT ON VIEW public.drafts_ext IS 'View of `drafts` extended with metadata of its specifications'; + + +-- +-- Name: evolutions; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.evolutions ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + job_status public.jsonb_obj DEFAULT '{"type": "queued"}'::jsonb NOT NULL, + logs_token uuid DEFAULT gen_random_uuid() NOT NULL, + user_id uuid DEFAULT auth.uid() NOT NULL, + draft_id public.flowid NOT NULL, + collections json NOT NULL, + auto_publish boolean DEFAULT false NOT NULL, + background boolean DEFAULT false NOT NULL, + CONSTRAINT evolutions_collections_check CHECK ((json_typeof(collections) = 'array'::text)) +); + + +ALTER TABLE public.evolutions OWNER TO postgres; + +-- +-- Name: TABLE evolutions; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.evolutions IS 'evolutions are operations which test and publish drafts into live specifications'; + + +-- +-- Name: COLUMN evolutions.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN evolutions.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN evolutions.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.id IS 'ID of the record'; + + +-- +-- Name: COLUMN evolutions.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN evolutions.job_status; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.job_status IS 'Server-side job executation status of the record'; + + +-- +-- Name: COLUMN evolutions.logs_token; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.logs_token IS 'Bearer token for accessing logs of the server-side operation'; + + +-- +-- Name: COLUMN evolutions.user_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.user_id IS 'User who created the evolution'; + + +-- +-- Name: COLUMN evolutions.draft_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.draft_id IS 'Draft that is updated to affect the re-creation of the collections'; + + +-- +-- Name: COLUMN evolutions.collections; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.collections IS 'The names of the collections to re-create'; + + +-- +-- Name: COLUMN evolutions.auto_publish; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.auto_publish IS 'whether to automatically publish the results of the evolution, if successful'; + + +-- +-- Name: COLUMN evolutions.background; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.evolutions.background IS 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; + + +-- +-- Name: flow_watermarks; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.flow_watermarks ( + slot text NOT NULL, + watermark text +); + + +ALTER TABLE public.flow_watermarks OWNER TO postgres; + +-- +-- Name: invoices_ext; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.invoices_ext AS + WITH has_bypassrls AS ( + SELECT (EXISTS ( SELECT 1 + FROM pg_roles + WHERE ((pg_roles.rolname = CURRENT_ROLE) AND (pg_roles.rolbypassrls = true)))) AS bypass + ), authorized_tenants AS ( + SELECT tenants.tenant, + tenants.created_at + FROM ((public.tenants + LEFT JOIN has_bypassrls ON (true)) + LEFT JOIN public.auth_roles('admin'::public.grant_capability) auth_roles(role_prefix, capability) ON (((tenants.tenant)::text ^@ (auth_roles.role_prefix)::text))) + WHERE (has_bypassrls.bypass OR (auth_roles.role_prefix IS NOT NULL)) + ) + SELECT (date_trunc('month'::text, ((h.report ->> 'billed_month'::text))::timestamp with time zone))::date AS date_start, + (((date_trunc('month'::text, ((h.report ->> 'billed_month'::text))::timestamp with time zone) + '1 mon'::interval) - '1 day'::interval))::date AS date_end, + (authorized_tenants.tenant)::text AS billed_prefix, + COALESCE(NULLIF((h.report -> 'line_items'::text), 'null'::jsonb), '[]'::jsonb) AS line_items, + (COALESCE(NULLIF((h.report -> 'subtotal'::text), 'null'::jsonb), to_jsonb(0)))::integer AS subtotal, + h.report AS extra, + 'final'::text AS invoice_type + FROM (internal.billing_historicals h + JOIN authorized_tenants ON (((h.tenant)::text ^@ (authorized_tenants.tenant)::text))) +UNION ALL + SELECT (date_trunc('month'::text, ((report.report ->> 'billed_month'::text))::timestamp with time zone))::date AS date_start, + (((date_trunc('month'::text, ((report.report ->> 'billed_month'::text))::timestamp with time zone) + '1 mon'::interval) - '1 day'::interval))::date AS date_end, + (authorized_tenants.tenant)::text AS billed_prefix, + COALESCE(NULLIF((report.report -> 'line_items'::text), 'null'::jsonb), '[]'::jsonb) AS line_items, + (COALESCE(NULLIF((report.report -> 'subtotal'::text), 'null'::jsonb), to_jsonb(0)))::integer AS subtotal, + report.report AS extra, + 'preview'::text AS invoice_type + FROM ((authorized_tenants + JOIN LATERAL generate_series((GREATEST('2023-08-01'::date, (date_trunc('month'::text, authorized_tenants.created_at))::date))::timestamp with time zone, date_trunc('month'::text, ((now())::date)::timestamp with time zone), '1 mon'::interval) invoice_month(invoice_month) ON ((NOT (EXISTS ( SELECT 1 + FROM internal.billing_historicals h + WHERE (((h.tenant)::text ^@ (authorized_tenants.tenant)::text) AND ((date_trunc('month'::text, ((h.report ->> 'billed_month'::text))::timestamp with time zone))::date = invoice_month.invoice_month))))))) + JOIN LATERAL internal.billing_report_202308((authorized_tenants.tenant)::public.catalog_prefix, invoice_month.invoice_month) report(report) ON (true)) +UNION ALL + SELECT manual_bills.date_start, + manual_bills.date_end, + (authorized_tenants.tenant)::text AS billed_prefix, + jsonb_build_array(jsonb_build_object('description', manual_bills.description, 'count', 1, 'rate', manual_bills.usd_cents, 'subtotal', manual_bills.usd_cents)) AS line_items, + manual_bills.usd_cents AS subtotal, + 'null'::jsonb AS extra, + 'manual'::text AS invoice_type + FROM (internal.manual_bills + JOIN authorized_tenants ON (((manual_bills.tenant)::text ^@ (authorized_tenants.tenant)::text))); + + +ALTER VIEW public.invoices_ext OWNER TO postgres; + +-- +-- Name: live_spec_flows; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.live_spec_flows ( + source_id public.flowid NOT NULL, + target_id public.flowid NOT NULL, + flow_type public.flow_type NOT NULL +); + + +ALTER TABLE public.live_spec_flows OWNER TO postgres; + +-- +-- Name: TABLE live_spec_flows; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.live_spec_flows IS 'Join table of directed data-flows between live specifications'; + + +-- +-- Name: COLUMN live_spec_flows.source_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_spec_flows.source_id IS 'Specification from which data originates'; + + +-- +-- Name: COLUMN live_spec_flows.target_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.live_spec_flows.target_id IS 'Specification to which data flows'; + + +-- +-- Name: lock_monitor; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.lock_monitor AS + SELECT COALESCE(((blockingl.relation)::regclass)::text, blockingl.locktype) AS locked_item, + (now() - blockeda.query_start) AS waiting_duration, + blockeda.pid AS blocked_pid, + blockeda.query AS blocked_query, + blockedl.mode AS blocked_mode, + blockinga.pid AS blocking_pid, + blockinga.query AS blocking_query, + blockingl.mode AS blocking_mode + FROM (((pg_locks blockedl + JOIN pg_stat_activity blockeda ON ((blockedl.pid = blockeda.pid))) + JOIN pg_locks blockingl ON ((((blockingl.transactionid = blockedl.transactionid) OR ((blockingl.relation = blockedl.relation) AND (blockingl.locktype = blockedl.locktype))) AND (blockedl.pid <> blockingl.pid)))) + JOIN pg_stat_activity blockinga ON (((blockingl.pid = blockinga.pid) AND (blockinga.datid = blockeda.datid)))) + WHERE ((NOT blockedl.granted) AND (blockinga.datname = current_database())); + + +ALTER VIEW public.lock_monitor OWNER TO postgres; + +-- +-- Name: old_catalog_stats; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.old_catalog_stats ( + catalog_name public.catalog_name NOT NULL, + grain text NOT NULL, + bytes_written_by_me bigint NOT NULL, + docs_written_by_me bigint NOT NULL, + bytes_read_by_me bigint NOT NULL, + docs_read_by_me bigint NOT NULL, + bytes_written_to_me bigint NOT NULL, + docs_written_to_me bigint NOT NULL, + bytes_read_from_me bigint NOT NULL, + docs_read_from_me bigint NOT NULL, + ts timestamp with time zone NOT NULL, + flow_document json NOT NULL, + errors integer DEFAULT 0 NOT NULL, + failures integer DEFAULT 0 NOT NULL, + warnings integer DEFAULT 0 NOT NULL +) +PARTITION BY LIST (SUBSTRING(catalog_name FROM 1 FOR POSITION(('/'::text) IN (catalog_name)))); + + +ALTER TABLE public.old_catalog_stats OWNER TO postgres; + +-- +-- Name: TABLE old_catalog_stats; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.old_catalog_stats IS 'Generated for materialization ops/Pompato/catalog-stats-view of collection ops/Pompato/catalog-stats'; + + +-- +-- Name: COLUMN old_catalog_stats.catalog_name; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.catalog_name IS 'Name of the Flow catalog +user-provided projection of JSON at: /catalogName with inferred types: [string]'; + + +-- +-- Name: COLUMN old_catalog_stats.grain; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.grain IS 'Time grain that the stats are aggregated over +auto-generated projection of JSON at: /grain with inferred types: [string]'; + + +-- +-- Name: COLUMN old_catalog_stats.bytes_written_by_me; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.bytes_written_by_me IS 'Total number of bytes representing the JSON encoded documents +user-provided projection of JSON at: /statsSummary/writtenByMe/bytesTotal with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.docs_written_by_me; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.docs_written_by_me IS 'Total number of documents +user-provided projection of JSON at: /statsSummary/writtenByMe/docsTotal with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.bytes_read_by_me; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.bytes_read_by_me IS 'Total number of bytes representing the JSON encoded documents +user-provided projection of JSON at: /statsSummary/readByMe/bytesTotal with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.docs_read_by_me; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.docs_read_by_me IS 'Total number of documents +user-provided projection of JSON at: /statsSummary/readByMe/docsTotal with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.bytes_written_to_me; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.bytes_written_to_me IS 'Total number of bytes representing the JSON encoded documents +user-provided projection of JSON at: /statsSummary/writtenToMe/bytesTotal with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.docs_written_to_me; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.docs_written_to_me IS 'Total number of documents +user-provided projection of JSON at: /statsSummary/writtenToMe/docsTotal with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.bytes_read_from_me; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.bytes_read_from_me IS 'Total number of bytes representing the JSON encoded documents +user-provided projection of JSON at: /statsSummary/readFromMe/bytesTotal with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.docs_read_from_me; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.docs_read_from_me IS 'Total number of documents +user-provided projection of JSON at: /statsSummary/readFromMe/docsTotal with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.ts; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.ts IS 'Timestamp of the catalog stat aggregate +auto-generated projection of JSON at: /ts with inferred types: [string]'; + + +-- +-- Name: COLUMN old_catalog_stats.flow_document; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.flow_document IS 'Flow catalog task stats +Statistics related to the processing of a Flow catalog. +user-provided projection of JSON at: with inferred types: [object]'; + + +-- +-- Name: COLUMN old_catalog_stats.errors; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.errors IS 'Total number of logged errors +user-provided projection of JSON at: /statsSummary/errors with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.failures; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.failures IS 'Total number of shard failures +user-provided projection of JSON at: /statsSummary/failures with inferred types: [integer]'; + + +-- +-- Name: COLUMN old_catalog_stats.warnings; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.old_catalog_stats.warnings IS 'Total number of logged warnings +user-provided projection of JSON at: /statsSummary/warnings with inferred types: [integer]'; + + +-- +-- Name: publication_specs_ext; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.publication_specs_ext AS + SELECT p.live_spec_id, + p.pub_id, + p.detail, + p.published_at, + p.spec, + p.spec_type, + p.user_id, + ls.catalog_name, + ls.last_pub_id, + u.email AS user_email, + u.full_name AS user_full_name, + u.avatar_url AS user_avatar_url, + ls.data_plane_id + FROM ((public.live_specs ls + JOIN public.publication_specs p ON (((ls.id)::macaddr8 = (p.live_spec_id)::macaddr8))) + CROSS JOIN LATERAL public.view_user_profile(p.user_id) u(user_id, email, full_name, avatar_url)) + WHERE (EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((ls.catalog_name)::text ^@ (r.role_prefix)::text))); + + +ALTER VIEW public.publication_specs_ext OWNER TO postgres; + +-- +-- Name: publications; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.publications ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + job_status public.jsonb_obj DEFAULT '{"type": "queued"}'::jsonb NOT NULL, + logs_token uuid DEFAULT gen_random_uuid() NOT NULL, + user_id uuid DEFAULT auth.uid() NOT NULL, + draft_id public.flowid NOT NULL, + dry_run boolean DEFAULT false NOT NULL, + auto_evolve boolean DEFAULT false NOT NULL, + background boolean DEFAULT false NOT NULL, + data_plane_name text DEFAULT 'ops/dp/public/gcp-us-central1-c1'::text NOT NULL, + pub_id public.flowid +); + + +ALTER TABLE public.publications OWNER TO postgres; + +-- +-- Name: TABLE publications; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.publications IS 'Publications are operations which test and publish drafts into live specifications'; + + +-- +-- Name: COLUMN publications.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN publications.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN publications.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.id IS 'ID of the record'; + + +-- +-- Name: COLUMN publications.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN publications.job_status; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.job_status IS 'Server-side job executation status of the record'; + + +-- +-- Name: COLUMN publications.logs_token; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.logs_token IS 'Bearer token for accessing logs of the server-side operation'; + + +-- +-- Name: COLUMN publications.user_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.user_id IS 'User who created the publication'; + + +-- +-- Name: COLUMN publications.draft_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.draft_id IS 'Draft which is published'; + + +-- +-- Name: COLUMN publications.dry_run; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.dry_run IS 'A dry-run publication will test and verify a draft, but doesn''t publish into live specifications'; + + +-- +-- Name: COLUMN publications.auto_evolve; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.auto_evolve IS 'Whether to automatically handle schema evolution if the publication fails due to incompatible collections. + If true, then an evolutions job will be created automatically if needed, and the results will be published again.'; + + +-- +-- Name: COLUMN publications.background; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.background IS 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; + + +-- +-- Name: COLUMN publications.pub_id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.publications.pub_id IS 'The effective publication id that was used by the publications handler +to commit a successful publication. This will be null if the publication +did not commit. If non-null, then this is the publication id that would +exist in the publication_specs table, and would be used as the last_pub_id +for any drafted specs'; + + +-- +-- Name: refresh_tokens; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.refresh_tokens ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + user_id uuid NOT NULL, + multi_use boolean DEFAULT false, + valid_for interval NOT NULL, + uses integer DEFAULT 0, + hash text NOT NULL +); + + +ALTER TABLE public.refresh_tokens OWNER TO postgres; + +-- +-- Name: COLUMN refresh_tokens.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.refresh_tokens.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN refresh_tokens.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.refresh_tokens.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN refresh_tokens.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.refresh_tokens.id IS 'ID of the record'; + + +-- +-- Name: COLUMN refresh_tokens.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.refresh_tokens.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: registered_avro_schemas; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.registered_avro_schemas ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + avro_schema json NOT NULL, + avro_schema_md5 text GENERATED ALWAYS AS (md5(TRIM(BOTH FROM (avro_schema)::text))) STORED, + catalog_name public.catalog_name NOT NULL, + registry_id integer NOT NULL +); + + +ALTER TABLE public.registered_avro_schemas OWNER TO postgres; + +-- +-- Name: TABLE registered_avro_schemas; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.registered_avro_schemas IS ' +Avro schemas registered with a globally unique, stable registery ID. + +This is used to emulate the behavior of Confluent Schema Registry when +transcoding collection documents into Avro for use with Dekaf, +which must encode each message with an Avro schema ID (registry_id). +'; + + +-- +-- Name: COLUMN registered_avro_schemas.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.registered_avro_schemas.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN registered_avro_schemas.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.registered_avro_schemas.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN registered_avro_schemas.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.registered_avro_schemas.id IS 'ID of the record'; + + +-- +-- Name: COLUMN registered_avro_schemas.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.registered_avro_schemas.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: registered_avro_schemas_registry_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres +-- + +CREATE SEQUENCE public.registered_avro_schemas_registry_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +ALTER SEQUENCE public.registered_avro_schemas_registry_id_seq OWNER TO postgres; + +-- +-- Name: registered_avro_schemas_registry_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: postgres +-- + +ALTER SEQUENCE public.registered_avro_schemas_registry_id_seq OWNED BY public.registered_avro_schemas.registry_id; + + +-- +-- Name: storage_mappings; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.storage_mappings ( + created_at timestamp with time zone DEFAULT now() NOT NULL, + detail text, + id public.flowid NOT NULL, + updated_at timestamp with time zone DEFAULT now() NOT NULL, + catalog_prefix public.catalog_prefix NOT NULL, + spec json NOT NULL +); + + +ALTER TABLE public.storage_mappings OWNER TO postgres; + +-- +-- Name: TABLE storage_mappings; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON TABLE public.storage_mappings IS 'Storage mappings which are applied to published specifications'; + + +-- +-- Name: COLUMN storage_mappings.created_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.storage_mappings.created_at IS 'Time at which the record was created'; + + +-- +-- Name: COLUMN storage_mappings.detail; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.storage_mappings.detail IS 'Description of the record'; + + +-- +-- Name: COLUMN storage_mappings.id; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.storage_mappings.id IS 'ID of the record'; + + +-- +-- Name: COLUMN storage_mappings.updated_at; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.storage_mappings.updated_at IS 'Time at which the record was last updated'; + + +-- +-- Name: COLUMN storage_mappings.catalog_prefix; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.storage_mappings.catalog_prefix IS 'Catalog prefix which this storage mapping prefixes'; + + +-- +-- Name: COLUMN storage_mappings.spec; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON COLUMN public.storage_mappings.spec IS 'Specification of this storage mapping'; + + +-- +-- Name: test_publication_specs_ext; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.test_publication_specs_ext AS + SELECT p.live_spec_id, + p.pub_id, + p.detail, + p.published_at, + p.spec, + p.spec_type, + p.user_id, + ls.catalog_name, + ls.last_pub_id, + u.email AS user_email, + u.full_name AS user_full_name, + u.avatar_url AS user_avatar_url, + ls.data_plane_id + FROM ((public.live_specs ls + JOIN public.publication_specs p ON (((ls.id)::macaddr8 = (p.live_spec_id)::macaddr8))) + CROSS JOIN LATERAL public.view_user_profile(p.user_id) u(user_id, email, full_name, avatar_url)) + WHERE (EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((ls.catalog_name)::text ^@ (r.role_prefix)::text))); + + +ALTER VIEW public.test_publication_specs_ext OWNER TO postgres; + +-- +-- Name: unchanged_draft_specs; Type: VIEW; Schema: public; Owner: postgres +-- + +CREATE VIEW public.unchanged_draft_specs AS + SELECT d.draft_id, + d.catalog_name, + d.spec_type, + d.live_spec_md5, + d.draft_spec_md5, + d.inferred_schema_md5, + d.live_inferred_schema_md5 + FROM public.draft_specs_ext d + WHERE (d.draft_spec_md5 = d.live_spec_md5); + + +ALTER VIEW public.unchanged_draft_specs OWNER TO postgres; + +-- +-- Name: VIEW unchanged_draft_specs; Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON VIEW public.unchanged_draft_specs IS 'View of `draft_specs_ext` that is filtered to only include specs that are identical to the + current `live_specs`.'; + + +-- +-- Name: catalog_stats_daily; Type: TABLE ATTACH; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.catalog_stats ATTACH PARTITION public.catalog_stats_daily FOR VALUES IN ('daily'); + + +-- +-- Name: catalog_stats_hourly; Type: TABLE ATTACH; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.catalog_stats ATTACH PARTITION public.catalog_stats_hourly FOR VALUES IN ('hourly'); + + +-- +-- Name: catalog_stats_monthly; Type: TABLE ATTACH; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.catalog_stats ATTACH PARTITION public.catalog_stats_monthly FOR VALUES IN ('monthly'); + + +-- +-- Name: registered_avro_schemas registry_id; Type: DEFAULT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.registered_avro_schemas ALTER COLUMN registry_id SET DEFAULT nextval('public.registered_avro_schemas_registry_id_seq'::regclass); + + +-- +-- Name: _model_async _model_async_pkey; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal._model_async + ADD CONSTRAINT _model_async_pkey PRIMARY KEY (id); + + +-- +-- Name: _model _model_pkey; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal._model + ADD CONSTRAINT _model_pkey PRIMARY KEY (id); + + +-- +-- Name: billing_adjustments billing_adjustments_pkey; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.billing_adjustments + ADD CONSTRAINT billing_adjustments_pkey PRIMARY KEY (id); + + +-- +-- Name: billing_historicals billing_historicals_tenant_billed_month_key; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.billing_historicals + ADD CONSTRAINT billing_historicals_tenant_billed_month_key UNIQUE (tenant, billed_month); + +ALTER TABLE ONLY internal.billing_historicals REPLICA IDENTITY USING INDEX billing_historicals_tenant_billed_month_key; + + +-- +-- Name: gateway_auth_keys gateway_auth_keys_pkey; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.gateway_auth_keys + ADD CONSTRAINT gateway_auth_keys_pkey PRIMARY KEY (id); + + +-- +-- Name: gateway_endpoints gateway_endpoints_pkey; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.gateway_endpoints + ADD CONSTRAINT gateway_endpoints_pkey PRIMARY KEY (id); + + +-- +-- Name: gcm_accounts gcm_accounts_pkey; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.gcm_accounts + ADD CONSTRAINT gcm_accounts_pkey PRIMARY KEY (id); + + +-- +-- Name: illegal_tenant_names illegal_tenant_names_pkey; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.illegal_tenant_names + ADD CONSTRAINT illegal_tenant_names_pkey PRIMARY KEY (name); + + +-- +-- Name: manual_bills manual_bills_pkey; Type: CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.manual_bills + ADD CONSTRAINT manual_bills_pkey PRIMARY KEY (tenant, date_start, date_end); + + +-- +-- Name: alert_data_processing alert_data_processing_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.alert_data_processing + ADD CONSTRAINT alert_data_processing_pkey PRIMARY KEY (catalog_name); + + +-- +-- Name: alert_history alert_history_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.alert_history + ADD CONSTRAINT alert_history_pkey PRIMARY KEY (alert_type, catalog_name, fired_at); + + +-- +-- Name: alert_subscriptions alert_subscriptions_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.alert_subscriptions + ADD CONSTRAINT alert_subscriptions_pkey PRIMARY KEY (id); + + +-- +-- Name: applied_directives applied_directives_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.applied_directives + ADD CONSTRAINT applied_directives_pkey PRIMARY KEY (id); + + +-- +-- Name: catalog_stats catalog_stats_pkey1; Type: CONSTRAINT; Schema: public; Owner: stats_loader +-- + +ALTER TABLE ONLY public.catalog_stats + ADD CONSTRAINT catalog_stats_pkey1 PRIMARY KEY (catalog_name, grain, ts); + + +-- +-- Name: catalog_stats_daily catalog_stats_daily_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.catalog_stats_daily + ADD CONSTRAINT catalog_stats_daily_pkey PRIMARY KEY (catalog_name, grain, ts); + + +-- +-- Name: catalog_stats_hourly catalog_stats_hourly_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.catalog_stats_hourly + ADD CONSTRAINT catalog_stats_hourly_pkey PRIMARY KEY (catalog_name, grain, ts); + + +-- +-- Name: catalog_stats_monthly catalog_stats_monthly_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.catalog_stats_monthly + ADD CONSTRAINT catalog_stats_monthly_pkey PRIMARY KEY (catalog_name, grain, ts); + + +-- +-- Name: connector_tags connector_tags_connector_id_image_tag_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.connector_tags + ADD CONSTRAINT connector_tags_connector_id_image_tag_key UNIQUE (connector_id, image_tag); + + +-- +-- Name: connector_tags connector_tags_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.connector_tags + ADD CONSTRAINT connector_tags_pkey PRIMARY KEY (id); + + +-- +-- Name: connectors connectors_image_name_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.connectors + ADD CONSTRAINT connectors_image_name_key UNIQUE (image_name); + + +-- +-- Name: connectors connectors_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.connectors + ADD CONSTRAINT connectors_pkey PRIMARY KEY (id); + + +-- +-- Name: controller_jobs controller_jobs_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.controller_jobs + ADD CONSTRAINT controller_jobs_pkey PRIMARY KEY (live_spec_id); + + +-- +-- Name: data_planes data_planes_data_plane_fqdn_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.data_planes + ADD CONSTRAINT data_planes_data_plane_fqdn_key UNIQUE (data_plane_fqdn); + + +-- +-- Name: data_planes data_planes_data_plane_name_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.data_planes + ADD CONSTRAINT data_planes_data_plane_name_key UNIQUE (data_plane_name); + + +-- +-- Name: data_planes data_planes_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.data_planes + ADD CONSTRAINT data_planes_pkey PRIMARY KEY (id); + + +-- +-- Name: directives directives_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.directives + ADD CONSTRAINT directives_pkey PRIMARY KEY (id); + + +-- +-- Name: directives directives_token_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.directives + ADD CONSTRAINT directives_token_key UNIQUE (token); + + +-- +-- Name: discovers discovers_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.discovers + ADD CONSTRAINT discovers_pkey PRIMARY KEY (id); + + +-- +-- Name: draft_specs draft_specs_draft_id_catalog_name_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.draft_specs + ADD CONSTRAINT draft_specs_draft_id_catalog_name_key UNIQUE (draft_id, catalog_name); + + +-- +-- Name: draft_specs draft_specs_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.draft_specs + ADD CONSTRAINT draft_specs_pkey PRIMARY KEY (id); + + +-- +-- Name: drafts drafts_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.drafts + ADD CONSTRAINT drafts_pkey PRIMARY KEY (id); + + +-- +-- Name: evolutions evolutions_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.evolutions + ADD CONSTRAINT evolutions_pkey PRIMARY KEY (id); + + +-- +-- Name: flow_watermarks flow_watermarks_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.flow_watermarks + ADD CONSTRAINT flow_watermarks_pkey PRIMARY KEY (slot); + + +-- +-- Name: inferred_schemas inferred_schemas_pkey; Type: CONSTRAINT; Schema: public; Owner: stats_loader +-- + +ALTER TABLE ONLY public.inferred_schemas + ADD CONSTRAINT inferred_schemas_pkey PRIMARY KEY (collection_name); + + +-- +-- Name: live_specs live_specs_catalog_name_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.live_specs + ADD CONSTRAINT live_specs_catalog_name_key UNIQUE (catalog_name); + + +-- +-- Name: live_specs live_specs_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.live_specs + ADD CONSTRAINT live_specs_pkey PRIMARY KEY (id); + + +-- +-- Name: publication_specs publication_specs_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.publication_specs + ADD CONSTRAINT publication_specs_pkey PRIMARY KEY (live_spec_id, pub_id); + + +-- +-- Name: publications publications_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.publications + ADD CONSTRAINT publications_pkey PRIMARY KEY (id); + + +-- +-- Name: refresh_tokens refresh_tokens_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.refresh_tokens + ADD CONSTRAINT refresh_tokens_pkey PRIMARY KEY (id); + + +-- +-- Name: registered_avro_schemas registered_avro_schemas_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.registered_avro_schemas + ADD CONSTRAINT registered_avro_schemas_pkey PRIMARY KEY (id); + + +-- +-- Name: registered_avro_schemas registered_avro_schemas_registry_id_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.registered_avro_schemas + ADD CONSTRAINT registered_avro_schemas_registry_id_key UNIQUE (registry_id); + + +-- +-- Name: role_grants role_grants_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.role_grants + ADD CONSTRAINT role_grants_pkey PRIMARY KEY (id); + + +-- +-- Name: role_grants role_grants_subject_role_object_role_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.role_grants + ADD CONSTRAINT role_grants_subject_role_object_role_key UNIQUE (subject_role, object_role); + + +-- +-- Name: storage_mappings storage_mappings_catalog_prefix_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.storage_mappings + ADD CONSTRAINT storage_mappings_catalog_prefix_key UNIQUE (catalog_prefix); + + +-- +-- Name: storage_mappings storage_mappings_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.storage_mappings + ADD CONSTRAINT storage_mappings_pkey PRIMARY KEY (id); + + +-- +-- Name: tenants tenants_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.tenants + ADD CONSTRAINT tenants_pkey PRIMARY KEY (id); + + +-- +-- Name: tenants tenants_tenant_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.tenants + ADD CONSTRAINT tenants_tenant_key UNIQUE (tenant); + + +-- +-- Name: user_grants user_grants_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.user_grants + ADD CONSTRAINT user_grants_pkey PRIMARY KEY (id); + + +-- +-- Name: user_grants user_grants_user_id_object_role_key; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.user_grants + ADD CONSTRAINT user_grants_user_id_object_role_key UNIQUE (user_id, object_role); + + +-- +-- Name: billing_historicals_tenant_starts_with; Type: INDEX; Schema: internal; Owner: postgres +-- + +CREATE INDEX billing_historicals_tenant_starts_with ON internal.billing_historicals USING btree (tenant COLLATE "C"); + + +-- +-- Name: idx_gcm_accounts_id_where_approved; Type: INDEX; Schema: internal; Owner: postgres +-- + +CREATE UNIQUE INDEX idx_gcm_accounts_id_where_approved ON internal.gcm_accounts USING btree (id) WHERE (approved = true); + + +-- +-- Name: idx_logs_token; Type: INDEX; Schema: internal; Owner: postgres +-- + +CREATE INDEX idx_logs_token ON internal.log_lines USING btree (token); + + +-- +-- Name: catalog_stats_catalog_index; Type: INDEX; Schema: public; Owner: stats_loader +-- + +CREATE INDEX catalog_stats_catalog_index ON ONLY public.catalog_stats USING btree (catalog_name); + + +-- +-- Name: catalog_stats_catalog_index_spgist; Type: INDEX; Schema: public; Owner: stats_loader +-- + +CREATE INDEX catalog_stats_catalog_index_spgist ON ONLY public.catalog_stats USING spgist (((catalog_name)::text)); + + +-- +-- Name: catalog_stats_daily_catalog_name_idx; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX catalog_stats_daily_catalog_name_idx ON public.catalog_stats_daily USING btree (catalog_name); + + +-- +-- Name: catalog_stats_daily_catalog_name_idx3; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX catalog_stats_daily_catalog_name_idx3 ON public.catalog_stats_daily USING spgist (((catalog_name)::text)); + + +-- +-- Name: catalog_stats_hourly_catalog_name_idx; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX catalog_stats_hourly_catalog_name_idx ON public.catalog_stats_hourly USING btree (catalog_name); + + +-- +-- Name: catalog_stats_hourly_catalog_name_idx3; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX catalog_stats_hourly_catalog_name_idx3 ON public.catalog_stats_hourly USING spgist (((catalog_name)::text)); + + +-- +-- Name: catalog_stats_monthly_catalog_name_idx; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX catalog_stats_monthly_catalog_name_idx ON public.catalog_stats_monthly USING btree (catalog_name); + + +-- +-- Name: catalog_stats_monthly_catalog_name_idx3; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX catalog_stats_monthly_catalog_name_idx3 ON public.catalog_stats_monthly USING spgist (((catalog_name)::text)); + + +-- +-- Name: discovers_queued; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX discovers_queued ON public.discovers USING btree (id) WHERE (((job_status)::jsonb ->> 'type'::text) = 'queued'::text); + + +-- +-- Name: evolutions_queued; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX evolutions_queued ON public.evolutions USING btree (id) WHERE (((job_status)::jsonb ->> 'type'::text) = 'queued'::text); + + +-- +-- Name: idx_catalog_stats_catalog_name_grain_ts; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_catalog_stats_catalog_name_grain_ts ON ONLY public.old_catalog_stats USING btree (catalog_name, grain, ts DESC); + + +-- +-- Name: idx_catalog_stats_grain_ts; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_catalog_stats_grain_ts ON ONLY public.old_catalog_stats USING btree (catalog_name, grain, ts DESC); + + +-- +-- Name: idx_connector_tags_id_where_queued; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE UNIQUE INDEX idx_connector_tags_id_where_queued ON public.connector_tags USING btree (id) WHERE (((job_status)::jsonb ->> 'type'::text) = 'queued'::text); + + +-- +-- Name: idx_directives_catalog_prefix; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_directives_catalog_prefix ON public.directives USING btree (catalog_prefix text_pattern_ops); + + +-- +-- Name: idx_draft_errors_draft_id; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_draft_errors_draft_id ON public.draft_errors USING btree (draft_id); + + +-- +-- Name: idx_drafts_user_id; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_drafts_user_id ON public.drafts USING btree (user_id); + + +-- +-- Name: idx_live_spec_flows_forward; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE UNIQUE INDEX idx_live_spec_flows_forward ON public.live_spec_flows USING btree (source_id, target_id) INCLUDE (flow_type); + + +-- +-- Name: idx_live_spec_flows_reverse; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE UNIQUE INDEX idx_live_spec_flows_reverse ON public.live_spec_flows USING btree (target_id, source_id) INCLUDE (flow_type); + + +-- +-- Name: idx_live_specs_catalog_name_spgist; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_live_specs_catalog_name_spgist ON public.live_specs USING spgist (((catalog_name)::text)); + + +-- +-- Name: idx_live_specs_spec_type; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_live_specs_spec_type ON public.live_specs USING btree (spec_type); + + +-- +-- Name: idx_live_specs_updated_at; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_live_specs_updated_at ON public.live_specs USING btree (updated_at DESC NULLS LAST); + + +-- +-- Name: idx_registered_avro_schemas_avro_schema_md5; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_registered_avro_schemas_avro_schema_md5 ON public.registered_avro_schemas USING btree (avro_schema_md5); + + +-- +-- Name: idx_role_grants_object_role_spgist; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_role_grants_object_role_spgist ON public.role_grants USING spgist (((object_role)::text)); + + +-- +-- Name: idx_role_grants_subject_role_spgist; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_role_grants_subject_role_spgist ON public.role_grants USING spgist (((subject_role)::text)); + + +-- +-- Name: idx_user_grants_object_role_spgist; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX idx_user_grants_object_role_spgist ON public.user_grants USING spgist (((object_role)::text)); + + +-- +-- Name: live_specs_controller_next_run; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX live_specs_controller_next_run ON public.live_specs USING btree (controller_next_run) INCLUDE (id) WHERE (controller_next_run IS NOT NULL); + + +-- +-- Name: publications_queued; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX publications_queued ON public.publications USING btree (id) WHERE (((job_status)::jsonb ->> 'type'::text) = 'queued'::text); + + +-- +-- Name: catalog_stats_daily_catalog_name_idx; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_catalog_index ATTACH PARTITION public.catalog_stats_daily_catalog_name_idx; + + +-- +-- Name: catalog_stats_daily_catalog_name_idx3; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_catalog_index_spgist ATTACH PARTITION public.catalog_stats_daily_catalog_name_idx3; + + +-- +-- Name: catalog_stats_daily_pkey; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_pkey1 ATTACH PARTITION public.catalog_stats_daily_pkey; + + +-- +-- Name: catalog_stats_hourly_catalog_name_idx; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_catalog_index ATTACH PARTITION public.catalog_stats_hourly_catalog_name_idx; + + +-- +-- Name: catalog_stats_hourly_catalog_name_idx3; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_catalog_index_spgist ATTACH PARTITION public.catalog_stats_hourly_catalog_name_idx3; + + +-- +-- Name: catalog_stats_hourly_pkey; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_pkey1 ATTACH PARTITION public.catalog_stats_hourly_pkey; + + +-- +-- Name: catalog_stats_monthly_catalog_name_idx; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_catalog_index ATTACH PARTITION public.catalog_stats_monthly_catalog_name_idx; + + +-- +-- Name: catalog_stats_monthly_catalog_name_idx3; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_catalog_index_spgist ATTACH PARTITION public.catalog_stats_monthly_catalog_name_idx3; + + +-- +-- Name: catalog_stats_monthly_pkey; Type: INDEX ATTACH; Schema: public; Owner: stats_loader +-- + +ALTER INDEX public.catalog_stats_pkey1 ATTACH PARTITION public.catalog_stats_monthly_pkey; + + +-- +-- Name: next_auto_discovers _RETURN; Type: RULE; Schema: internal; Owner: postgres +-- + +CREATE OR REPLACE VIEW internal.next_auto_discovers AS + SELECT live_specs.id AS capture_id, + live_specs.catalog_name AS capture_name, + (((live_specs.spec -> 'endpoint'::text) -> 'connector'::text) -> 'config'::text) AS endpoint_json, + COALESCE((((live_specs.spec -> 'autoDiscover'::text) ->> 'addNewBindings'::text))::boolean, false) AS add_new_bindings, + COALESCE((((live_specs.spec -> 'autoDiscover'::text) ->> 'evolveIncompatibleCollections'::text))::boolean, false) AS evolve_incompatible_collections, + connector_tags.id AS connector_tags_id, + ((now() - GREATEST(max(discovers.updated_at), live_specs.updated_at)) + connector_tags.auto_discover_interval) AS overdue_interval + FROM (((public.live_specs + LEFT JOIN public.discovers ON (((live_specs.catalog_name)::text = (discovers.capture_name)::text))) + JOIN public.connectors ON ((live_specs.connector_image_name = connectors.image_name))) + JOIN public.connector_tags ON ((((connectors.id)::macaddr8 = (connector_tags.connector_id)::macaddr8) AND (live_specs.connector_image_tag = connector_tags.image_tag)))) + WHERE ((live_specs.spec_type = 'capture'::public.catalog_spec_type) AND (NOT COALESCE((((live_specs.spec -> 'shards'::text) ->> 'disable'::text))::boolean, false)) AND (COALESCE(json_typeof((live_specs.spec -> 'autoDiscover'::text)), 'null'::text) <> 'null'::text)) + GROUP BY live_specs.id, connector_tags.id + HAVING ((now() - GREATEST(max(discovers.updated_at), live_specs.updated_at)) > connector_tags.auto_discover_interval) + ORDER BY ((now() - GREATEST(max(discovers.updated_at), live_specs.updated_at)) + connector_tags.auto_discover_interval) DESC; + + +-- +-- Name: tenants Grant support role access to tenants; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER "Grant support role access to tenants" AFTER INSERT OR UPDATE ON public.tenants FOR EACH STATEMENT EXECUTE FUNCTION internal.update_support_role(); + + +-- +-- Name: alert_history Send email after alert fired; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER "Send email after alert fired" AFTER INSERT ON public.alert_history FOR EACH ROW EXECUTE FUNCTION internal.send_alerts(); + + +-- +-- Name: alert_history Send email after alert resolved; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER "Send email after alert resolved" AFTER UPDATE ON public.alert_history FOR EACH ROW WHEN (((old.resolved_at IS NULL) AND (new.resolved_at IS NOT NULL))) EXECUTE FUNCTION internal.send_alerts(); + + +-- +-- Name: applied_directives Verify delete of applied directives; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER "Verify delete of applied directives" BEFORE DELETE ON public.applied_directives FOR EACH ROW EXECUTE FUNCTION internal.on_applied_directives_delete(); + + +-- +-- Name: applied_directives Verify update of applied directives; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER "Verify update of applied directives" BEFORE UPDATE ON public.applied_directives FOR EACH ROW EXECUTE FUNCTION internal.on_applied_directives_update(); + + +-- +-- Name: applied_directives applied_directives_agent_notifications; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER applied_directives_agent_notifications AFTER INSERT OR UPDATE ON public.applied_directives FOR EACH ROW WHEN ((((new.job_status)::jsonb ->> 'type'::text) = 'queued'::text)) EXECUTE FUNCTION internal.notify_agent(); + + +-- +-- Name: connector_tags connector_tags_agent_notifications; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER connector_tags_agent_notifications AFTER INSERT OR UPDATE ON public.connector_tags FOR EACH ROW WHEN ((((new.job_status)::jsonb ->> 'type'::text) = 'queued'::text)) EXECUTE FUNCTION internal.notify_agent(); + + +-- +-- Name: discovers discovers_agent_notifications; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER discovers_agent_notifications AFTER INSERT OR UPDATE ON public.discovers FOR EACH ROW WHEN ((((new.job_status)::jsonb ->> 'type'::text) = 'queued'::text)) EXECUTE FUNCTION internal.notify_agent(); + + +-- +-- Name: evolutions evolutions_agent_notifications; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER evolutions_agent_notifications AFTER INSERT OR UPDATE ON public.evolutions FOR EACH ROW WHEN ((((new.job_status)::jsonb ->> 'type'::text) = 'queued'::text)) EXECUTE FUNCTION internal.notify_agent(); + + +-- +-- Name: inferred_schemas inferred_schema_controller_insert; Type: TRIGGER; Schema: public; Owner: stats_loader +-- + +CREATE TRIGGER inferred_schema_controller_insert AFTER INSERT ON public.inferred_schemas FOR EACH ROW EXECUTE FUNCTION internal.on_inferred_schema_update(); + + +-- +-- Name: inferred_schemas inferred_schema_controller_update; Type: TRIGGER; Schema: public; Owner: stats_loader +-- + +CREATE TRIGGER inferred_schema_controller_update AFTER UPDATE ON public.inferred_schemas FOR EACH ROW WHEN ((old.md5 IS DISTINCT FROM new.md5)) EXECUTE FUNCTION internal.on_inferred_schema_update(); + + +-- +-- Name: publications publications_agent_notifications; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER publications_agent_notifications AFTER INSERT OR UPDATE ON public.publications FOR EACH ROW WHEN ((((new.job_status)::jsonb ->> 'type'::text) = 'queued'::text)) EXECUTE FUNCTION internal.notify_agent(); + + +-- +-- Name: connectors update-marketing-site-on-connector-change; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER "update-marketing-site-on-connector-change" AFTER INSERT OR DELETE OR UPDATE ON public.connectors FOR EACH ROW EXECUTE FUNCTION supabase_functions.http_request('https://strapi.estuary.dev/api', 'POST', '{"Authorization":"Bearer supersecretpassword"}', '{"event_type":"database_updated","repo":"estuary/marketing-site"}', '1000'); + + +-- +-- Name: connector_tags update-marketing-site-on-connector-tags-change; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER "update-marketing-site-on-connector-tags-change" AFTER INSERT OR DELETE OR UPDATE ON public.connector_tags FOR EACH ROW EXECUTE FUNCTION supabase_functions.http_request('https://strapi.estuary.dev/api', 'POST', '{"Authorization":"Bearer supersecretpassword"}', '{"event_type":"database_updated","repo":"estuary/marketing-site"}', '1000'); + + +-- +-- Name: billing_adjustments billing_adjustments_tenant_fkey; Type: FK CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.billing_adjustments + ADD CONSTRAINT billing_adjustments_tenant_fkey FOREIGN KEY (tenant) REFERENCES public.tenants(tenant); + + +-- +-- Name: manual_bills manual_bills_tenant_fkey; Type: FK CONSTRAINT; Schema: internal; Owner: postgres +-- + +ALTER TABLE ONLY internal.manual_bills + ADD CONSTRAINT manual_bills_tenant_fkey FOREIGN KEY (tenant) REFERENCES public.tenants(tenant); + + +-- +-- Name: applied_directives applied_directives_directive_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.applied_directives + ADD CONSTRAINT applied_directives_directive_id_fkey FOREIGN KEY (directive_id) REFERENCES public.directives(id); + + +-- +-- Name: applied_directives applied_directives_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.applied_directives + ADD CONSTRAINT applied_directives_user_id_fkey FOREIGN KEY (user_id) REFERENCES auth.users(id); + + +-- +-- Name: connector_tags connector_tags_connector_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.connector_tags + ADD CONSTRAINT connector_tags_connector_id_fkey FOREIGN KEY (connector_id) REFERENCES public.connectors(id); + + +-- +-- Name: controller_jobs controller_jobs_live_spec_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.controller_jobs + ADD CONSTRAINT controller_jobs_live_spec_id_fkey FOREIGN KEY (live_spec_id) REFERENCES public.live_specs(id) ON DELETE CASCADE; + + +-- +-- Name: discovers discovers_connector_tag_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.discovers + ADD CONSTRAINT discovers_connector_tag_id_fkey FOREIGN KEY (connector_tag_id) REFERENCES public.connector_tags(id); + + +-- +-- Name: discovers discovers_draft_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.discovers + ADD CONSTRAINT discovers_draft_id_fkey FOREIGN KEY (draft_id) REFERENCES public.drafts(id) ON DELETE CASCADE; + + +-- +-- Name: draft_errors draft_errors_draft_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.draft_errors + ADD CONSTRAINT draft_errors_draft_id_fkey FOREIGN KEY (draft_id) REFERENCES public.drafts(id) ON DELETE CASCADE; + + +-- +-- Name: draft_specs draft_specs_draft_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.draft_specs + ADD CONSTRAINT draft_specs_draft_id_fkey FOREIGN KEY (draft_id) REFERENCES public.drafts(id) ON DELETE CASCADE; + + +-- +-- Name: drafts drafts_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.drafts + ADD CONSTRAINT drafts_user_id_fkey FOREIGN KEY (user_id) REFERENCES auth.users(id); + + +-- +-- Name: evolutions evolutions_draft_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.evolutions + ADD CONSTRAINT evolutions_draft_id_fkey FOREIGN KEY (draft_id) REFERENCES public.drafts(id) ON DELETE CASCADE; + + +-- +-- Name: evolutions evolutions_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.evolutions + ADD CONSTRAINT evolutions_user_id_fkey FOREIGN KEY (user_id) REFERENCES auth.users(id); + + +-- +-- Name: live_spec_flows live_spec_flows_source_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.live_spec_flows + ADD CONSTRAINT live_spec_flows_source_id_fkey FOREIGN KEY (source_id) REFERENCES public.live_specs(id) ON DELETE CASCADE; + + +-- +-- Name: live_spec_flows live_spec_flows_target_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.live_spec_flows + ADD CONSTRAINT live_spec_flows_target_id_fkey FOREIGN KEY (target_id) REFERENCES public.live_specs(id) ON DELETE CASCADE; + + +-- +-- Name: publication_specs publication_specs_live_spec_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.publication_specs + ADD CONSTRAINT publication_specs_live_spec_id_fkey FOREIGN KEY (live_spec_id) REFERENCES public.live_specs(id) ON DELETE CASCADE; + + +-- +-- Name: publication_specs publication_specs_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.publication_specs + ADD CONSTRAINT publication_specs_user_id_fkey FOREIGN KEY (user_id) REFERENCES auth.users(id); + + +-- +-- Name: publications publications_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.publications + ADD CONSTRAINT publications_user_id_fkey FOREIGN KEY (user_id) REFERENCES auth.users(id); + + +-- +-- Name: refresh_tokens refresh_tokens_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.refresh_tokens + ADD CONSTRAINT refresh_tokens_user_id_fkey FOREIGN KEY (user_id) REFERENCES auth.users(id); + + +-- +-- Name: tenants tenants_gcm_account_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.tenants + ADD CONSTRAINT tenants_gcm_account_id_fkey FOREIGN KEY (gcm_account_id) REFERENCES internal.gcm_accounts(id); + + +-- +-- Name: user_grants user_grants_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.user_grants + ADD CONSTRAINT user_grants_user_id_fkey FOREIGN KEY (user_id) REFERENCES auth.users(id); + + +-- +-- Name: alert_history Users access alert history for admin-authorized tasks; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users access alert history for admin-authorized tasks" ON public.alert_history USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((alert_history.catalog_name)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: alert_data_processing Users access alerts for admin-authorized tasks; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users access alerts for admin-authorized tasks" ON public.alert_data_processing USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((alert_data_processing.catalog_name)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: alert_subscriptions Users access subscriptions for the prefixes they admin; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users access subscriptions for the prefixes they admin" ON public.alert_subscriptions USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((alert_subscriptions.catalog_prefix)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: discovers Users access their discovers; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users access their discovers" ON public.discovers USING (((draft_id)::macaddr8 IN ( SELECT drafts.id + FROM public.drafts))); + + +-- +-- Name: draft_specs Users access their draft specs; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users access their draft specs" ON public.draft_specs USING (((draft_id)::macaddr8 IN ( SELECT drafts.id + FROM public.drafts + WHERE (drafts.user_id = ( SELECT auth.uid() AS uid))))); + + +-- +-- Name: directives Users can access and change directives which they administer; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can access and change directives which they administer" ON public.directives USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((directives.catalog_prefix)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: draft_errors Users can access and delete errors of their drafts; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can access and delete errors of their drafts" ON public.draft_errors USING (((draft_id)::macaddr8 IN ( SELECT drafts.id + FROM public.drafts + WHERE (drafts.user_id = ( SELECT auth.uid() AS uid))))); + + +-- +-- Name: applied_directives Users can access only their applied directives; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can access only their applied directives" ON public.applied_directives USING ((user_id = ( SELECT auth.uid() AS uid))); + + +-- +-- Name: drafts Users can access only their created drafts; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can access only their created drafts" ON public.drafts USING ((user_id = ( SELECT auth.uid() AS uid))); + + +-- +-- Name: evolutions Users can access only their initiated evolution operations; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can access only their initiated evolution operations" ON public.evolutions FOR SELECT USING ((user_id = ( SELECT auth.uid() AS uid))); + + +-- +-- Name: publications Users can access only their initiated publish operations; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can access only their initiated publish operations" ON public.publications FOR SELECT USING ((user_id = ( SELECT auth.uid() AS uid))); + + +-- +-- Name: refresh_tokens Users can access their own refresh tokens; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can access their own refresh tokens" ON public.refresh_tokens USING ((user_id = ( SELECT auth.uid() AS uid))); + + +-- +-- Name: evolutions Users can insert evolutions from permitted drafts; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can insert evolutions from permitted drafts" ON public.evolutions FOR INSERT WITH CHECK (((draft_id)::macaddr8 IN ( SELECT drafts.id + FROM public.drafts))); + + +-- +-- Name: publications Users can insert publications from permitted drafts; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users can insert publications from permitted drafts" ON public.publications FOR INSERT WITH CHECK (((draft_id)::macaddr8 IN ( SELECT drafts.id + FROM public.drafts))); + + +-- +-- Name: role_grants Users delete role grants where they admin the object or subject; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users delete role grants where they admin the object or subject" ON public.role_grants FOR DELETE USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE (((role_grants.object_role)::text ^@ (r.role_prefix)::text) OR ((role_grants.subject_role)::text ^@ (r.role_prefix)::text))))); + + +-- +-- Name: user_grants Users delete user grants they admin or are the subject; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users delete user grants they admin or are the subject" ON public.user_grants FOR DELETE USING (((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((user_grants.object_role)::text ^@ (r.role_prefix)::text))) OR (user_id = ( SELECT auth.uid() AS uid)))); + + +-- +-- Name: role_grants Users insert role grants where they admin the object; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users insert role grants where they admin the object" ON public.role_grants FOR INSERT WITH CHECK ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((role_grants.object_role)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: user_grants Users insert user grants they admin; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users insert user grants they admin" ON public.user_grants FOR INSERT WITH CHECK ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((user_grants.object_role)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: directives Users may select directives which they have applied; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users may select directives which they have applied" ON public.directives FOR SELECT USING (((id)::macaddr8 IN ( SELECT applied_directives.directive_id + FROM public.applied_directives))); + + +-- +-- Name: controller_jobs Users must be authorized to live specifications; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be authorized to live specifications" ON public.controller_jobs FOR SELECT USING (((live_spec_id)::macaddr8 IN ( SELECT live_specs.id + FROM public.live_specs))); + + +-- +-- Name: live_spec_flows Users must be authorized to one referenced specification; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be authorized to one referenced specification" ON public.live_spec_flows FOR SELECT USING ((((source_id)::macaddr8 IN ( SELECT live_specs.id + FROM public.live_specs)) OR ((target_id)::macaddr8 IN ( SELECT live_specs.id + FROM public.live_specs)))); + + +-- +-- Name: catalog_stats Users must be authorized to the catalog name; Type: POLICY; Schema: public; Owner: stats_loader +-- + +CREATE POLICY "Users must be authorized to the catalog name" ON public.catalog_stats FOR SELECT USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((catalog_stats.catalog_name)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: old_catalog_stats Users must be authorized to the catalog name; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be authorized to the catalog name" ON public.old_catalog_stats FOR SELECT USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((old_catalog_stats.catalog_name)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: inferred_schemas Users must be authorized to the collection name; Type: POLICY; Schema: public; Owner: stats_loader +-- + +CREATE POLICY "Users must be authorized to the collection name" ON public.inferred_schemas FOR SELECT USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((inferred_schemas.collection_name)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: storage_mappings Users must be authorized to the specification catalog prefix; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be authorized to the specification catalog prefix" ON public.storage_mappings FOR SELECT USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((storage_mappings.catalog_prefix)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: tenants Users must be authorized to their catalog tenant; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be authorized to their catalog tenant" ON public.tenants FOR SELECT USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((tenants.tenant)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: data_planes Users must be read-authorized to data planes; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be read-authorized to data planes" ON public.data_planes FOR SELECT USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((data_planes.data_plane_name)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: registered_avro_schemas Users must be read-authorized to the schema catalog name; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be read-authorized to the schema catalog name" ON public.registered_avro_schemas USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((registered_avro_schemas.catalog_name)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: live_specs Users must be read-authorized to the specification catalog name; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be read-authorized to the specification catalog name" ON public.live_specs FOR SELECT USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('read'::public.grant_capability) r(role_prefix, capability) + WHERE ((live_specs.catalog_name)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: publication_specs Users must be read-authorized to the specification catalog name; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users must be read-authorized to the specification catalog name" ON public.publication_specs FOR SELECT USING (((live_spec_id)::macaddr8 IN ( SELECT live_specs.id + FROM public.live_specs))); + + +-- +-- Name: role_grants Users select role grants where they admin the subject or object; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users select role grants where they admin the subject or object" ON public.role_grants FOR SELECT USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE (((role_grants.object_role)::text ^@ (r.role_prefix)::text) OR ((role_grants.subject_role)::text ^@ (r.role_prefix)::text))))); + + +-- +-- Name: user_grants Users select user grants they admin or are the subject; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users select user grants they admin or are the subject" ON public.user_grants FOR SELECT USING (((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((user_grants.object_role)::text ^@ (r.role_prefix)::text))) OR (user_id = ( SELECT auth.uid() AS uid)))); + + +-- +-- Name: role_grants Users update role grants where they admin the object; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users update role grants where they admin the object" ON public.role_grants FOR UPDATE USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((role_grants.object_role)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: user_grants Users update user grants they admin; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "Users update user grants they admin" ON public.user_grants FOR UPDATE USING ((EXISTS ( SELECT 1 + FROM public.auth_roles('admin'::public.grant_capability) r(role_prefix, capability) + WHERE ((user_grants.object_role)::text ^@ (r.role_prefix)::text)))); + + +-- +-- Name: alert_data_processing; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.alert_data_processing ENABLE ROW LEVEL SECURITY; + +-- +-- Name: alert_history; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.alert_history ENABLE ROW LEVEL SECURITY; + +-- +-- Name: alert_subscriptions; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.alert_subscriptions ENABLE ROW LEVEL SECURITY; + +-- +-- Name: applied_directives; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.applied_directives ENABLE ROW LEVEL SECURITY; + +-- +-- Name: catalog_stats; Type: ROW SECURITY; Schema: public; Owner: stats_loader +-- + +ALTER TABLE public.catalog_stats ENABLE ROW LEVEL SECURITY; + +-- +-- Name: controller_jobs; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.controller_jobs ENABLE ROW LEVEL SECURITY; + +-- +-- Name: data_planes; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.data_planes ENABLE ROW LEVEL SECURITY; + +-- +-- Name: directives; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.directives ENABLE ROW LEVEL SECURITY; + +-- +-- Name: discovers; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.discovers ENABLE ROW LEVEL SECURITY; + +-- +-- Name: draft_errors; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.draft_errors ENABLE ROW LEVEL SECURITY; + +-- +-- Name: draft_specs; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.draft_specs ENABLE ROW LEVEL SECURITY; + +-- +-- Name: drafts; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.drafts ENABLE ROW LEVEL SECURITY; + +-- +-- Name: evolutions; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.evolutions ENABLE ROW LEVEL SECURITY; + +-- +-- Name: inferred_schemas; Type: ROW SECURITY; Schema: public; Owner: stats_loader +-- + +ALTER TABLE public.inferred_schemas ENABLE ROW LEVEL SECURITY; + +-- +-- Name: live_spec_flows; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.live_spec_flows ENABLE ROW LEVEL SECURITY; + +-- +-- Name: live_specs; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.live_specs ENABLE ROW LEVEL SECURITY; + +-- +-- Name: tenants marketplace_integration can see all tenants; Type: POLICY; Schema: public; Owner: postgres +-- + +CREATE POLICY "marketplace_integration can see all tenants" ON public.tenants TO marketplace_integration USING (true) WITH CHECK (true); + + +-- +-- Name: old_catalog_stats; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.old_catalog_stats ENABLE ROW LEVEL SECURITY; + +-- +-- Name: publication_specs; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.publication_specs ENABLE ROW LEVEL SECURITY; + +-- +-- Name: publications; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.publications ENABLE ROW LEVEL SECURITY; + +-- +-- Name: refresh_tokens; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.refresh_tokens ENABLE ROW LEVEL SECURITY; + +-- +-- Name: registered_avro_schemas; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.registered_avro_schemas ENABLE ROW LEVEL SECURITY; + +-- +-- Name: role_grants; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.role_grants ENABLE ROW LEVEL SECURITY; + +-- +-- Name: storage_mappings; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.storage_mappings ENABLE ROW LEVEL SECURITY; + +-- +-- Name: tenants; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.tenants ENABLE ROW LEVEL SECURITY; + +-- +-- Name: user_grants; Type: ROW SECURITY; Schema: public; Owner: postgres +-- + +ALTER TABLE public.user_grants ENABLE ROW LEVEL SECURITY; + +-- +-- Name: SCHEMA internal; Type: ACL; Schema: -; Owner: postgres +-- + +GRANT USAGE ON SCHEMA internal TO marketplace_integration; + + +-- +-- Name: SCHEMA public; Type: ACL; Schema: -; Owner: postgres +-- + +REVOKE USAGE ON SCHEMA public FROM PUBLIC; +GRANT USAGE ON SCHEMA public TO anon; +GRANT USAGE ON SCHEMA public TO authenticated; +GRANT USAGE ON SCHEMA public TO service_role; +GRANT USAGE ON SCHEMA public TO gatsby_reader; +GRANT ALL ON SCHEMA public TO stats_loader; +GRANT USAGE ON SCHEMA public TO github_action_connector_refresh; +GRANT USAGE ON SCHEMA public TO marketplace_integration; +GRANT USAGE ON SCHEMA public TO wgd_automation; + + +-- +-- Name: TABLE applied_directives; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.applied_directives TO service_role; +GRANT SELECT,DELETE ON TABLE public.applied_directives TO authenticated; +GRANT SELECT ON TABLE public.applied_directives TO reporting_user; + + +-- +-- Name: COLUMN applied_directives.user_claims; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT UPDATE(user_claims) ON TABLE public.applied_directives TO authenticated; + + +-- +-- Name: TABLE directives; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.directives TO service_role; +GRANT ALL ON TABLE public.directives TO authenticated; +GRANT SELECT ON TABLE public.directives TO reporting_user; + + +-- +-- Name: FUNCTION auth_roles(min_capability public.grant_capability); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.auth_roles(min_capability public.grant_capability) TO service_role; + + +-- +-- Name: FUNCTION auth_uid(); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.auth_uid() TO service_role; + + +-- +-- Name: FUNCTION billing_report_202308(billed_prefix public.catalog_prefix, billed_month timestamp with time zone, free_trial_range tstzrange); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.billing_report_202308(billed_prefix public.catalog_prefix, billed_month timestamp with time zone, free_trial_range tstzrange) TO service_role; + + +-- +-- Name: FUNCTION create_refresh_token(multi_use boolean, valid_for interval, detail text); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.create_refresh_token(multi_use boolean, valid_for interval, detail text) TO service_role; + + +-- +-- Name: FUNCTION draft_collections_eligible_for_deletion(capture_id public.flowid, draft_id public.flowid); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.draft_collections_eligible_for_deletion(capture_id public.flowid, draft_id public.flowid) TO service_role; + + +-- +-- Name: FUNCTION exchange_directive_token(bearer_token uuid); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.exchange_directive_token(bearer_token uuid) TO service_role; + + +-- +-- Name: FUNCTION gateway_auth_token(VARIADIC prefixes text[]); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.gateway_auth_token(VARIADIC prefixes text[]) TO service_role; + + +-- +-- Name: FUNCTION generate_access_token(refresh_token_id public.flowid, secret text); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.generate_access_token(refresh_token_id public.flowid, secret text) TO service_role; + + +-- +-- Name: FUNCTION generate_opengraph_value(opengraph_raw jsonb, opengraph_patch jsonb, field text); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.generate_opengraph_value(opengraph_raw jsonb, opengraph_patch jsonb, field text) TO service_role; + + +-- +-- Name: FUNCTION prune_unchanged_draft_specs(prune_draft_id public.flowid); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.prune_unchanged_draft_specs(prune_draft_id public.flowid) TO service_role; + + +-- +-- Name: FUNCTION republish_prefix(prefix public.catalog_prefix); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.republish_prefix(prefix public.catalog_prefix) TO service_role; + + +-- +-- Name: FUNCTION tier_line_items(amount numeric, tiers integer[], name text, unit text); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.tier_line_items(amount numeric, tiers integer[], name text, unit text) TO service_role; + + +-- +-- Name: FUNCTION user_info_summary(); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.user_info_summary() TO service_role; + + +-- +-- Name: FUNCTION view_logs(bearer_token uuid); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.view_logs(bearer_token uuid) TO service_role; + + +-- +-- Name: FUNCTION view_user_profile(bearer_user_id uuid); Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON FUNCTION public.view_user_profile(bearer_user_id uuid) TO service_role; + + +-- +-- Name: TABLE alert_data_processing; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.alert_data_processing TO service_role; +GRANT SELECT,INSERT,DELETE ON TABLE public.alert_data_processing TO authenticated; + + +-- +-- Name: COLUMN alert_data_processing.evaluation_interval; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT UPDATE(evaluation_interval) ON TABLE public.alert_data_processing TO authenticated; + + +-- +-- Name: TABLE alert_subscriptions; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.alert_subscriptions TO service_role; +GRANT SELECT,INSERT,DELETE,UPDATE ON TABLE public.alert_subscriptions TO authenticated; + + +-- +-- Name: TABLE catalog_stats; Type: ACL; Schema: public; Owner: stats_loader +-- + +GRANT ALL ON TABLE public.catalog_stats TO service_role; +GRANT SELECT ON TABLE public.catalog_stats TO authenticated; + + +-- +-- Name: TABLE catalog_stats_hourly; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.catalog_stats_hourly TO service_role; +GRANT SELECT ON TABLE public.catalog_stats_hourly TO wgd_automation; + + +-- +-- Name: TABLE live_specs; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.live_specs TO service_role; +GRANT SELECT ON TABLE public.live_specs TO authenticated; +GRANT SELECT ON TABLE public.live_specs TO reporting_user; +GRANT SELECT ON TABLE public.live_specs TO wgd_automation; + + +-- +-- Name: TABLE tenants; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.tenants TO service_role; +GRANT SELECT ON TABLE public.tenants TO authenticated; +GRANT SELECT ON TABLE public.tenants TO reporting_user; +GRANT SELECT,REFERENCES,UPDATE ON TABLE public.tenants TO marketplace_integration; + + +-- +-- Name: TABLE billing_historicals; Type: ACL; Schema: internal; Owner: postgres +-- + +GRANT ALL ON TABLE internal.billing_historicals TO service_role; + + +-- +-- Name: TABLE gcm_accounts; Type: ACL; Schema: internal; Owner: postgres +-- + +GRANT SELECT,INSERT,UPDATE ON TABLE internal.gcm_accounts TO marketplace_integration; + + +-- +-- Name: TABLE manual_bills; Type: ACL; Schema: internal; Owner: postgres +-- + +GRANT SELECT,INSERT,UPDATE ON TABLE internal.manual_bills TO marketplace_integration; + + +-- +-- Name: TABLE catalog_stats_daily; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.catalog_stats_daily TO service_role; +GRANT SELECT ON TABLE public.catalog_stats_daily TO wgd_automation; + + +-- +-- Name: TABLE catalog_stats_monthly; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.catalog_stats_monthly TO service_role; + + +-- +-- Name: TABLE user_profiles; Type: ACL; Schema: internal; Owner: postgres +-- + +GRANT SELECT ON TABLE internal.user_profiles TO authenticated; +GRANT SELECT ON TABLE internal.user_profiles TO reporting_user; + + +-- +-- Name: TABLE alert_all; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.alert_all TO service_role; + + +-- +-- Name: TABLE alert_history; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.alert_history TO service_role; +GRANT SELECT ON TABLE public.alert_history TO authenticated; + + +-- +-- Name: TABLE role_grants; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.role_grants TO authenticated; +GRANT ALL ON TABLE public.role_grants TO service_role; +GRANT SELECT ON TABLE public.role_grants TO reporting_user; +GRANT ALL ON TABLE public.role_grants TO marketplace_integration; + + +-- +-- Name: TABLE user_grants; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.user_grants TO service_role; +GRANT ALL ON TABLE public.user_grants TO authenticated; +GRANT SELECT ON TABLE public.user_grants TO reporting_user; + + +-- +-- Name: TABLE combined_grants_ext; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.combined_grants_ext TO service_role; +GRANT SELECT ON TABLE public.combined_grants_ext TO authenticated; +GRANT SELECT ON TABLE public.combined_grants_ext TO reporting_user; + + +-- +-- Name: TABLE connector_tags; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.connector_tags TO service_role; +GRANT SELECT ON TABLE public.connector_tags TO authenticated; +GRANT ALL ON TABLE public.connector_tags TO github_action_connector_refresh; +GRANT SELECT ON TABLE public.connector_tags TO gatsby_reader; +GRANT SELECT ON TABLE public.connector_tags TO reporting_user; + + +-- +-- Name: TABLE connectors; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.connectors TO service_role; +GRANT SELECT ON TABLE public.connectors TO github_action_connector_refresh; +GRANT SELECT ON TABLE public.connectors TO gatsby_reader; +GRANT SELECT ON TABLE public.connectors TO reporting_user; + + +-- +-- Name: COLUMN connectors.created_at; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(created_at) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.detail; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(detail) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(id) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.updated_at; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(updated_at) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.external_url; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(external_url) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.image_name; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(image_name) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.oauth2_client_id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(oauth2_client_id) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.short_description; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(short_description) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.title; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(title) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.logo_url; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(logo_url) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: COLUMN connectors.recommended; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(recommended) ON TABLE public.connectors TO authenticated; + + +-- +-- Name: TABLE controller_jobs; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.controller_jobs TO service_role; +GRANT SELECT ON TABLE public.controller_jobs TO reporting_user; + + +-- +-- Name: TABLE data_planes; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.data_planes TO service_role; +GRANT SELECT ON TABLE public.data_planes TO reporting_user; + + +-- +-- Name: COLUMN data_planes.created_at; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(created_at) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(id) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.updated_at; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(updated_at) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.data_plane_name; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(data_plane_name) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.data_plane_fqdn; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(data_plane_fqdn) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.ops_logs_name; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(ops_logs_name) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.ops_stats_name; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(ops_stats_name) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.broker_address; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(broker_address) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.reactor_address; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(reactor_address) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.config; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(config) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.status; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(status) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.aws_iam_user_arn; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(aws_iam_user_arn) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.cidr_blocks; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(cidr_blocks) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: COLUMN data_planes.gcp_service_account_email; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(gcp_service_account_email) ON TABLE public.data_planes TO authenticated; + + +-- +-- Name: TABLE discovers; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.discovers TO service_role; +GRANT SELECT ON TABLE public.discovers TO authenticated; +GRANT SELECT ON TABLE public.discovers TO reporting_user; + + +-- +-- Name: COLUMN discovers.capture_name; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(capture_name) ON TABLE public.discovers TO authenticated; + + +-- +-- Name: COLUMN discovers.connector_tag_id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(connector_tag_id) ON TABLE public.discovers TO authenticated; + + +-- +-- Name: COLUMN discovers.draft_id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(draft_id) ON TABLE public.discovers TO authenticated; + + +-- +-- Name: COLUMN discovers.endpoint_config; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(endpoint_config) ON TABLE public.discovers TO authenticated; + + +-- +-- Name: COLUMN discovers.update_only; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(update_only) ON TABLE public.discovers TO authenticated; + + +-- +-- Name: COLUMN discovers.data_plane_name; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(data_plane_name) ON TABLE public.discovers TO authenticated; + + +-- +-- Name: TABLE draft_errors; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT,DELETE ON TABLE public.draft_errors TO authenticated; +GRANT ALL ON TABLE public.draft_errors TO service_role; +GRANT SELECT ON TABLE public.draft_errors TO reporting_user; + + +-- +-- Name: TABLE draft_specs; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.draft_specs TO service_role; +GRANT ALL ON TABLE public.draft_specs TO authenticated; +GRANT SELECT ON TABLE public.draft_specs TO reporting_user; + + +-- +-- Name: TABLE drafts; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.drafts TO service_role; +GRANT SELECT,DELETE ON TABLE public.drafts TO authenticated; +GRANT SELECT ON TABLE public.drafts TO reporting_user; + + +-- +-- Name: COLUMN drafts.detail; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(detail),UPDATE(detail) ON TABLE public.drafts TO authenticated; + + +-- +-- Name: TABLE inferred_schemas; Type: ACL; Schema: public; Owner: stats_loader +-- + +GRANT ALL ON TABLE public.inferred_schemas TO service_role; +GRANT SELECT ON TABLE public.inferred_schemas TO authenticated; + + +-- +-- Name: TABLE publication_specs; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.publication_specs TO service_role; +GRANT SELECT ON TABLE public.publication_specs TO authenticated; +GRANT SELECT ON TABLE public.publication_specs TO reporting_user; + + +-- +-- Name: TABLE live_specs_ext; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.live_specs_ext TO service_role; +GRANT SELECT ON TABLE public.live_specs_ext TO reporting_user; +GRANT SELECT ON TABLE public.live_specs_ext TO authenticated; + + +-- +-- Name: TABLE draft_specs_ext; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.draft_specs_ext TO service_role; +GRANT SELECT ON TABLE public.draft_specs_ext TO reporting_user; +GRANT SELECT ON TABLE public.draft_specs_ext TO authenticated; + + +-- +-- Name: TABLE drafts_ext; Type: ACL; Schema: public; Owner: authenticated +-- + +GRANT ALL ON TABLE public.drafts_ext TO service_role; +GRANT SELECT ON TABLE public.drafts_ext TO reporting_user; + + +-- +-- Name: TABLE evolutions; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.evolutions TO service_role; +GRANT SELECT ON TABLE public.evolutions TO authenticated; + + +-- +-- Name: COLUMN evolutions.detail; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(detail) ON TABLE public.evolutions TO authenticated; + + +-- +-- Name: COLUMN evolutions.draft_id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(draft_id) ON TABLE public.evolutions TO authenticated; + + +-- +-- Name: COLUMN evolutions.collections; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(collections) ON TABLE public.evolutions TO authenticated; + + +-- +-- Name: TABLE flow_watermarks; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.flow_watermarks TO service_role; +GRANT ALL ON TABLE public.flow_watermarks TO reporting_user; + + +-- +-- Name: TABLE invoices_ext; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.invoices_ext TO service_role; +GRANT SELECT ON TABLE public.invoices_ext TO authenticated; + + +-- +-- Name: TABLE live_spec_flows; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.live_spec_flows TO service_role; +GRANT SELECT ON TABLE public.live_spec_flows TO reporting_user; +GRANT SELECT ON TABLE public.live_spec_flows TO authenticated; + + +-- +-- Name: TABLE lock_monitor; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.lock_monitor TO service_role; +GRANT SELECT ON TABLE public.lock_monitor TO reporting_user; + + +-- +-- Name: TABLE old_catalog_stats; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.old_catalog_stats TO service_role; +GRANT SELECT ON TABLE public.old_catalog_stats TO authenticated; +GRANT SELECT ON TABLE public.old_catalog_stats TO reporting_user; + + +-- +-- Name: TABLE publication_specs_ext; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.publication_specs_ext TO service_role; +GRANT SELECT ON TABLE public.publication_specs_ext TO reporting_user; +GRANT SELECT ON TABLE public.publication_specs_ext TO authenticated; + + +-- +-- Name: TABLE publications; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.publications TO service_role; +GRANT SELECT ON TABLE public.publications TO authenticated; +GRANT SELECT ON TABLE public.publications TO reporting_user; + + +-- +-- Name: COLUMN publications.detail; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(detail) ON TABLE public.publications TO authenticated; + + +-- +-- Name: COLUMN publications.draft_id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(draft_id) ON TABLE public.publications TO authenticated; + + +-- +-- Name: COLUMN publications.dry_run; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(dry_run) ON TABLE public.publications TO authenticated; + + +-- +-- Name: COLUMN publications.data_plane_name; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(data_plane_name) ON TABLE public.publications TO authenticated; + + +-- +-- Name: TABLE refresh_tokens; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.refresh_tokens TO service_role; +GRANT DELETE ON TABLE public.refresh_tokens TO authenticated; +GRANT SELECT ON TABLE public.refresh_tokens TO reporting_user; + + +-- +-- Name: COLUMN refresh_tokens.created_at; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(created_at) ON TABLE public.refresh_tokens TO authenticated; + + +-- +-- Name: COLUMN refresh_tokens.detail; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(detail),UPDATE(detail) ON TABLE public.refresh_tokens TO authenticated; + + +-- +-- Name: COLUMN refresh_tokens.id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(id) ON TABLE public.refresh_tokens TO authenticated; + + +-- +-- Name: COLUMN refresh_tokens.updated_at; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(updated_at) ON TABLE public.refresh_tokens TO authenticated; + + +-- +-- Name: COLUMN refresh_tokens.user_id; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(user_id) ON TABLE public.refresh_tokens TO authenticated; + + +-- +-- Name: COLUMN refresh_tokens.multi_use; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(multi_use),UPDATE(multi_use) ON TABLE public.refresh_tokens TO authenticated; + + +-- +-- Name: COLUMN refresh_tokens.valid_for; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(valid_for),UPDATE(valid_for) ON TABLE public.refresh_tokens TO authenticated; + + +-- +-- Name: COLUMN refresh_tokens.uses; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT SELECT(uses) ON TABLE public.refresh_tokens TO authenticated; + + +-- +-- Name: TABLE registered_avro_schemas; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.registered_avro_schemas TO service_role; +GRANT SELECT ON TABLE public.registered_avro_schemas TO reporting_user; +GRANT SELECT ON TABLE public.registered_avro_schemas TO authenticated; + + +-- +-- Name: COLUMN registered_avro_schemas.updated_at; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT UPDATE(updated_at) ON TABLE public.registered_avro_schemas TO authenticated; + + +-- +-- Name: COLUMN registered_avro_schemas.avro_schema; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(avro_schema) ON TABLE public.registered_avro_schemas TO authenticated; + + +-- +-- Name: COLUMN registered_avro_schemas.catalog_name; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT INSERT(catalog_name) ON TABLE public.registered_avro_schemas TO authenticated; + + +-- +-- Name: SEQUENCE registered_avro_schemas_registry_id_seq; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON SEQUENCE public.registered_avro_schemas_registry_id_seq TO service_role; +GRANT USAGE ON SEQUENCE public.registered_avro_schemas_registry_id_seq TO authenticated; + + +-- +-- Name: TABLE storage_mappings; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.storage_mappings TO service_role; +GRANT SELECT ON TABLE public.storage_mappings TO authenticated; +GRANT SELECT ON TABLE public.storage_mappings TO reporting_user; + + +-- +-- Name: TABLE test_publication_specs_ext; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.test_publication_specs_ext TO service_role; +GRANT SELECT ON TABLE public.test_publication_specs_ext TO reporting_user; +GRANT SELECT ON TABLE public.test_publication_specs_ext TO authenticated; + + +-- +-- Name: TABLE unchanged_draft_specs; Type: ACL; Schema: public; Owner: postgres +-- + +GRANT ALL ON TABLE public.unchanged_draft_specs TO service_role; +GRANT SELECT ON TABLE public.unchanged_draft_specs TO reporting_user; +GRANT SELECT ON TABLE public.unchanged_draft_specs TO authenticated; + + +-- +-- Name: DEFAULT PRIVILEGES FOR SEQUENCES; Type: DEFAULT ACL; Schema: public; Owner: postgres +-- + +ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA public GRANT ALL ON SEQUENCES TO postgres; +ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA public GRANT ALL ON SEQUENCES TO service_role; + + +-- +-- Name: DEFAULT PRIVILEGES FOR SEQUENCES; Type: DEFAULT ACL; Schema: public; Owner: supabase_admin +-- + + + +-- +-- Name: DEFAULT PRIVILEGES FOR FUNCTIONS; Type: DEFAULT ACL; Schema: public; Owner: postgres +-- + +ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA public GRANT ALL ON FUNCTIONS TO postgres; +ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA public GRANT ALL ON FUNCTIONS TO service_role; + + +-- +-- Name: DEFAULT PRIVILEGES FOR FUNCTIONS; Type: DEFAULT ACL; Schema: public; Owner: supabase_admin +-- + + + +-- +-- Name: DEFAULT PRIVILEGES FOR TABLES; Type: DEFAULT ACL; Schema: public; Owner: postgres +-- + +ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA public GRANT ALL ON TABLES TO postgres; +ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA public GRANT ALL ON TABLES TO service_role; +ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA public GRANT SELECT ON TABLES TO reporting_user; + + +-- +-- Name: DEFAULT PRIVILEGES FOR TABLES; Type: DEFAULT ACL; Schema: public; Owner: supabase_admin +-- + + + +-- +-- PostgreSQL database dump complete +-- + diff --git a/supabase/migrations/20_auto_discovers.sql b/supabase/migrations/20_auto_discovers.sql deleted file mode 100644 index 2b12510c8a..0000000000 --- a/supabase/migrations/20_auto_discovers.sql +++ /dev/null @@ -1,116 +0,0 @@ - - -create view internal.next_auto_discovers as -select - live_specs.id as capture_id, - live_specs.catalog_name as capture_name, - live_specs.spec->'endpoint'->'connector'->'config' as endpoint_json, - -- These properties default to false, which matches the behavior in the models crate. - coalesce((live_specs.spec->'autoDiscover'->>'addNewBindings')::boolean, false) as add_new_bindings, - coalesce((live_specs.spec->'autoDiscover'->>'evolveIncompatibleCollections')::boolean, false) as evolve_incompatible_collections, - connector_tags.id as connector_tags_id, - -- We use the greater of the timestamp of the most recent discover and the - -- capture spec updated_at timestamp as the starting point. This is required - -- because a successful publication will cause the discover to be deleted. And - -- we also don't want autoDiscover to run right after a user runs a discover - -- via the UI, or if the last discover was unsuccessful (and thus wasn't - -- deleted). - now() - greatest(max(discovers.updated_at), live_specs.updated_at) + connector_tags.auto_discover_interval as overdue_interval -from live_specs -left join discovers on live_specs.catalog_name = discovers.capture_name --- We can only perform discovers if we have the connectors and tags rows present. --- I'd consider it an improvement if we could somehow refactor this to log a warning in cases where there's no connector_tag -inner join connectors - on live_specs.connector_image_name = connectors.image_name -inner join connector_tags - on connectors.id = connector_tags.connector_id - and live_specs.connector_image_tag = connector_tags.image_tag -where - live_specs.spec_type = 'capture' - -- We don't want to discover if shards are disabled - and not coalesce((live_specs.spec->'shards'->>'disable')::boolean, false) - -- Any non-null value for autoDiscover will enable it, but we need to deal with the difference between - -- a JSON null and a postgres NULL. - and coalesce(json_typeof(live_specs.spec->'autoDiscover'), 'null') != 'null' -group by live_specs.id, connector_tags.id --- See comment on overdue_interval above -having now() - greatest(max(discovers.updated_at), live_specs.updated_at) > connector_tags.auto_discover_interval --- This ordering isn't strictly necessary, but it helps to keep the output consistent for testing -order by overdue_interval desc; - -comment on view internal.next_auto_discovers is -'A view of captures that are due for an automatic discovery operation. -This is determined by comparing the time of the last discover operation -against the curent time'; - -comment on column internal.next_auto_discovers.capture_id is 'Primary key of the live_specs row for the capture'; -comment on column internal.next_auto_discovers.capture_name is 'Catalog name of the capture'; -comment on column internal.next_auto_discovers.endpoint_json is -'The endpoint configuration of the capture, to use with the next discover.'; -comment on column internal.next_auto_discovers.add_new_bindings is -'Whether to add newly discovered bindings. If false, then it will only update existing bindings.'; -comment on column internal.next_auto_discovers.evolve_incompatible_collections is -'Whether to automatically perform schema evolution in the event that the newly discovered collections are incompatble.'; -comment on column internal.next_auto_discovers.connector_tags_id is -'The id of the connector_tags row that corresponds to the image used by this capture.'; - - -create or replace function internal.create_auto_discovers() -returns integer as $$ -declare - support_user_id uuid = (select id from auth.users where email = 'support@estuary.dev'); - next_row internal.next_auto_discovers; - total_created integer := 0; - tmp_draft_id flowid; - tmp_discover_id flowid; -begin - -for next_row in select * from internal.next_auto_discovers -loop - -- Create a draft, which we'll discover into - insert into drafts (user_id) values (support_user_id) returning id into tmp_draft_id; - - insert into discovers (capture_name, draft_id, connector_tag_id, endpoint_config, update_only, auto_publish, auto_evolve) - values ( - next_row.capture_name, - tmp_draft_id, - next_row.connector_tags_id, - next_row.endpoint_json, - not next_row.add_new_bindings, - true, - next_row.evolve_incompatible_collections - ) returning id into tmp_discover_id; - - -- This is just useful when invoking the function manually. - total_created := total_created + 1; -end loop; - -return total_created; -end; -$$ language plpgsql security definer; - -comment on function internal.create_auto_discovers is -'Creates discovers jobs for each capture that is due for an automatic discover. Each disocver will have auto_publish -set to true. The update_only and auto_evolve columns of the discover will be set based on the addNewBindings and -evolveIncompatibleCollections fields in the capture spec. This function is idempotent. Once a discover is created by -this function, the next_auto_discovers view will no longer include that capture until its interval has passed again. -So its safe to call this function at basically any frequency. The return value of the function is the count of newly -created discovers jobs.'; - - --- The following enables the regularly scheduled function that creates --- discover jobs for captures with autoDiscover enabled. It's left commented --- out here because it's actually rather inconvenient to run during local --- development. 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 create_auto_discovers() --- whenever you want to trigger it. - --- create extension pg_cron with schema extensions; --- Sets up the periodic check for captures that need discovered --- select cron.schedule ( --- 'create-discovers', -- name of the cron job --- '*/5 * * * *', -- every 5 minutes, check to see if a discover needs run --- $$ select internal.create_auto_discovers() $$ --- ); - diff --git a/supabase/migrations/21_billing_v2.sql b/supabase/migrations/21_billing_v2.sql deleted file mode 100644 index d163c95bb0..0000000000 --- a/supabase/migrations/21_billing_v2.sql +++ /dev/null @@ -1,330 +0,0 @@ - --- Always use a transaction, y'all. -begin; - --- Grain is not actually used anywhere. --- It was originally intended for `catalog_stats` but isn't used and won't be. -drop type grain; - --- Transition `catalog_stats` to be a partitioned table on grain. -alter table catalog_stats rename to catalog_stats_old; - -create table catalog_stats ( - catalog_name catalog_name not null, - grain text not null, - ts timestamptz not null, - bytes_written_by_me bigint not null default 0, - docs_written_by_me bigint not null default 0, - bytes_read_by_me bigint not null default 0, - docs_read_by_me bigint not null default 0, - bytes_written_to_me bigint not null default 0, - docs_written_to_me bigint not null default 0, - bytes_read_from_me bigint not null default 0, - docs_read_from_me bigint not null default 0, - usage_seconds integer not null default 0, - warnings integer not null default 0, - errors integer not null default 0, - failures integer not null default 0, - flow_document json not null, - primary key (catalog_name, grain, ts) -) partition by list (grain); - -create table catalog_stats_monthly partition of catalog_stats for values in ('monthly'); -create table catalog_stats_daily partition of catalog_stats for values in ('daily'); -create table catalog_stats_hourly partition of catalog_stats for values in ('hourly'); - -alter table catalog_stats enable row level security; - -create policy "Users must be authorized to the catalog name" - on catalog_stats as permissive for select - using (exists( - select 1 from auth_roles('read') r where catalog_name ^@ r.role_prefix - )); -grant select on catalog_stats to authenticated; - -comment on table catalog_stats is - 'Statistics for Flow catalogs'; -comment on column catalog_stats.grain is ' -Time grain that stats are summed over. - -One of "monthly", "daily", or "hourly". -'; -comment on column catalog_stats.bytes_written_by_me is - 'Bytes written by this catalog, summed over the time grain.'; -comment on column catalog_stats.docs_written_by_me is - 'Documents written by this catalog, summed over the time grain.'; -comment on column catalog_stats.bytes_read_by_me is - 'Bytes read by this catalog, summed over the time grain.'; -comment on column catalog_stats.docs_read_by_me is - 'Documents read by this catalog, summed over the time grain.'; -comment on column catalog_stats.bytes_written_to_me is - 'Bytes written to this catalog, summed over the time grain.'; -comment on column catalog_stats.docs_written_to_me is - 'Documents written to this catalog, summed over the time grain.'; -comment on column catalog_stats.bytes_read_from_me is - 'Bytes read from this catalog, summed over the time grain.'; -comment on column catalog_stats.docs_read_from_me is - 'Documents read from this catalog, summed over the time grain.'; -comment on column catalog_stats.usage_seconds is - 'Metered usage of this catalog task.'; -comment on column catalog_stats.ts is ' -Timestamp indicating the start time of the time grain. - -Monthly grains start on day 1 of the month, at hour 0 and minute 0. -Daily grains start on the day, at hour 0 and minute 0. -Hourly grains start on the hour, at minute 0. -'; -comment on column catalog_stats.flow_document is - 'Aggregated statistics document for the given catalog name and grain'; - --- Populate our rebuilt table. -insert into catalog_stats ( - catalog_name, - grain, - ts, - bytes_written_by_me, - docs_written_by_me, - bytes_read_by_me, - docs_read_by_me, - bytes_written_to_me, - docs_written_to_me, - bytes_read_from_me, - docs_read_from_me, - warnings, - errors, - failures, - flow_document -) -select - catalog_name, - grain, - ts, - bytes_written_by_me, - docs_written_by_me, - bytes_read_by_me, - docs_read_by_me, - bytes_written_to_me, - docs_written_to_me, - bytes_read_from_me, - docs_read_from_me, - warnings, - errors, - failures, - flow_document -from catalog_stats_old; - -alter table catalog_stats owner to stats_loader; -drop table catalog_stats_old; - - --- Internal table used for one-off or negotiated adjustments. -create table internal.billing_adjustments ( - like internal._model including all, - - tenant catalog_tenant not null references tenants(tenant), - billed_month timestamptz not null, - usd_cents integer not null, - authorizer text not null, - - constraint "billed_month must be at a month boundary" check ( - billed_month = date_trunc('month', billed_month) - ) -); - -comment on table internal.billing_adjustments is - 'Internal table for authorized adjustments to tenant invoices, such as make-goods or negotiated service fees'; -comment on column internal.billing_adjustments.tenant is - 'Tenant which is being credited or debited.'; -comment on column internal.billing_adjustments.billed_month is - 'Month to which the adjustment is applied'; -comment on column internal.billing_adjustments.usd_cents is - 'Amount of adjustment. Positive values make the bill larger, negative values make it smaller'; -comment on column internal.billing_adjustments.authorizer is - 'Estuary employee who authorizes the adjustment'; - - --- Billing report which is effective August 2023. -create function billing_report_202308(billed_prefix catalog_prefix, billed_month timestamptz) -returns jsonb as $$ -#variable_conflict use_variable -declare - -- 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; - 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 - 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; - - --- Add data & usage tiers to tenants, as well as any recurring service charge. -alter table tenants add column data_tiers integer[] not null default '{50, 1024, 20}'; -alter table tenants add constraint "data_tiers is odd" check (array_length(data_tiers, 1) % 2 = 1 ); -alter table tenants add column usage_tiers integer[] not null default '{14}'; -alter table tenants add constraint "usage_tiers is odd" check (array_length(usage_tiers, 1) % 2 = 1); -alter table tenants add column recurring_usd_cents integer not null default 0; - -comment on column tenants.tasks_quota is - 'Maximum number of active tasks that the tenant may have'; -comment on column tenants.collections_quota is - 'Maximum number of collections that the tenant may have'; -comment on column tenants.data_tiers is ' -Tiered data processing volumes and prices. - -Structured as an odd-length array of a price (in cents) followed by a volume (in GB). -For example, `{50, 1024, 30, 2048, 20}` is interpreted as: - * $0.50 per GB for the first TB (1,024 GB). - * $0.30 per GB for the next two TB (3TB cumulative). - * $0.20 per GB thereafter. -'; -comment on column tenants.usage_tiers is ' -Tiered task usage quantities and prices. - -Structured as an odd-length array of a price (in cents) followed by a quantity (in hours). -For example, `{30, 1440, 20, 2880, 15}` is interpreted as: - * $0.30 per hour for the first 1,440 hours. - * $0.20 per hour for the next 2,880 hours (4,320 hours total). - * $0.15 per hour thereafter. -'; -comment on column tenants.recurring_usd_cents is ' -Recurring monthly cost incurred by a tenant under a contracted relationship, in US cents (1/100ths of a USD). -'; - -commit; \ No newline at end of file diff --git a/supabase/migrations/22_inferred_schemas.sql b/supabase/migrations/22_inferred_schemas.sql deleted file mode 100644 index 71ffb9d5f1..0000000000 --- a/supabase/migrations/22_inferred_schemas.sql +++ /dev/null @@ -1,28 +0,0 @@ -begin; - -create table inferred_schemas ( - collection_name catalog_name not null, - "schema" json not null, - flow_document json not null, - primary key (collection_name) -); -alter table inferred_schemas enable row level security; - -create policy "Users must be authorized to the collection name" - on inferred_schemas as permissive for select - using (exists( - select 1 from auth_roles('read') r where collection_name ^@ r.role_prefix - )); -grant select on inferred_schemas to authenticated; - -comment on table inferred_schemas is - 'Inferred schemas of Flow collections'; -comment on column inferred_schemas.collection_name is - 'Collection which is inferred'; -comment on column inferred_schemas.schema is - 'Inferred JSON schema of collection documents.'; - --- stats_loader loads directly to the inferred_schemas table. -alter table inferred_schemas owner to stats_loader; - -commit; \ No newline at end of file diff --git a/supabase/migrations/23_live_specs_index.sql b/supabase/migrations/23_live_specs_index.sql deleted file mode 100644 index 9acbd7da1b..0000000000 --- a/supabase/migrations/23_live_specs_index.sql +++ /dev/null @@ -1,4 +0,0 @@ --- Migration to add an index to live_specs to support --- looking up materializations by their `sourceCapture`. - -create index idx_live_specs_materializations_by_source_capture on live_specs ((spec->>'sourceCapture')); diff --git a/supabase/migrations/24_billing_historicals.sql b/supabase/migrations/24_billing_historicals.sql deleted file mode 100644 index 8582f47820..0000000000 --- a/supabase/migrations/24_billing_historicals.sql +++ /dev/null @@ -1,234 +0,0 @@ - --- 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; - diff --git a/supabase/migrations/25_fix_billing_security.sql b/supabase/migrations/25_fix_billing_security.sql deleted file mode 100644 index d4578705ec..0000000000 --- a/supabase/migrations/25_fix_billing_security.sql +++ /dev/null @@ -1,166 +0,0 @@ -begin; - --- 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 the real active role has bypassrls flag set. - -- Because this function is SECURITY DEFINER, both `current_user` and `current_role` - -- will be `postgres`, which does have bypassrls set. Instead we want the - -- role of the caller, which can be accessed like so according to: - -- https://www.postgresql.org/message-id/13906.1141711109%40sss.pgh.pa.us - perform * from pg_roles where rolname = current_setting('role') and rolbypassrls = true; - has_bypassrls = found; - - if not has_admin_grant and not has_bypassrls 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; - -commit; \ No newline at end of file diff --git a/supabase/migrations/26_delete_old_rows.sql b/supabase/migrations/26_delete_old_rows.sql deleted file mode 100644 index 9217f6f421..0000000000 --- a/supabase/migrations/26_delete_old_rows.sql +++ /dev/null @@ -1,49 +0,0 @@ -begin; --- The purpose of this is to cleanup old drafts, draft_specs, discovers, evolutions, etc. --- These things can pile up over time, and there's no need to retain them for a long time. --- Note that the cleanup of draft_specs, discovers, and evolutions happens due to cascading --- deletions from drafts. - --- We need to add the foreign key constraint to evolutions, since it was not there originally. -delete from evolutions e where not exists (select d.id from drafts d where d.id = e.draft_id); -alter table evolutions add foreign key (draft_id) references drafts(id) on delete cascade; - -create or replace function internal.delete_old_rows() -returns jsonb as $$ -declare - n_drafts integer; - n_logs integer; - n_hourly_stats integer; -begin - with d as ( - delete from public.drafts where updated_at < (now() - '10 days'::interval) returning * - ) - select into n_drafts count(*) as n from d; - - -- log_lines gets a lot of volume, so we use a much shorter retention period with them. - with l as ( - delete from internal.log_lines where logged_at < (now() - '2 days'::interval) returning * - ) - select into n_logs count(*) as n from l; - - with s as ( - delete from catalog_stats_hourly where grain = 'hourly' and ts < (now() - '30 days'::interval) returning * - ) - select into n_hourly_stats count(*) from s; - - return json_build_object( - 'drafts', coalesce(n_drafts, 0), - 'log_lines', coalesce(n_logs, 0), - 'catalog_stats_hourly', coalesce(n_hourly_stats, 0) - ); -end; -$$ language plpgsql security definer; - -create extension if not exists pg_cron with schema extensions; -select cron.schedule( - 'delete-drafts', -- name of the cron job - '0 05 * * *', -- Every day at 05:00Z - $$ select internal.delete_old_rows() $$ -); - -commit; diff --git a/supabase/migrations/27_cascade_publication_specs.sql b/supabase/migrations/27_cascade_publication_specs.sql deleted file mode 100644 index 76549eccb9..0000000000 --- a/supabase/migrations/27_cascade_publication_specs.sql +++ /dev/null @@ -1,13 +0,0 @@ - --- Adds "on delete cascade" to the foreign key constraint on publication_specs to live_specs. --- We previously never deleted live_specs, but now we do as part of pruning unbound collections --- from in-progress publications. -begin; - -alter table publication_specs drop constraint publication_specs_live_spec_id_fkey; -alter table publication_specs add constraint publication_specs_live_spec_id_fkey - foreign key (live_spec_id) - references live_specs(id) - on delete cascade; - -commit; \ No newline at end of file diff --git a/supabase/migrations/28_free_trial.sql b/supabase/migrations/28_free_trial.sql deleted file mode 100644 index 203a9e047f..0000000000 --- a/supabase/migrations/28_free_trial.sql +++ /dev/null @@ -1,258 +0,0 @@ -begin; - -alter table tenants add column trial_start date; - --- Compute a JSONB array of line-items detailing usage under a tenant's effective tiers. -create or replace function tier_line_items( - -- Ammount of usage we're breaking out. - amount numeric, - -- Effective tenant tiers as ordered pairs of (quantity, cents), followed - -- by a final unpaired cents for unbounded usage beyond the final quantity. - tiers integer[], - -- Descriptive name of the tiered thing ("Data processing"). - name text, - -- Unit of the tier ("GB" or "hour"). - unit text -) -returns jsonb as $$ -declare - o_line_items jsonb = '[]'; -- Output variable. - tier_count numeric; - tier_pivot integer; - tier_rate integer; -begin - - for idx in 1..array_length(tiers, 1) by 2 loop - tier_rate = tiers[idx]; - tier_pivot = tiers[idx+1]; - tier_count = least(amount, tier_pivot); - amount = amount - tier_count; - - o_line_items = o_line_items || jsonb_build_object( - 'description', format( - case - when tier_pivot is null then '%1$s (at %4$s/%2$s)' -- Data processing (at $0.50/GB) - when idx = 1 then '%1s (first %3$s %2$ss at %4$s/%2$s)' -- Data processing (first 30 GBs at $0.50/GB) - else '%1$s (next %3$s %2$ss at %4$s/%2$s)' -- Data processing (next 6 GBs at $0.25/GB) - end, - name, - unit, - tier_pivot, - (tier_rate / 100.0)::money - ), - 'count', tier_count, - 'rate', tier_rate, - 'subtotal', round(tier_count * tier_rate) - ); - end loop; - - return o_line_items; - -end -$$ language plpgsql; - - --- Billing report which is effective August 2023. -create or replace function billing_report_202308(billed_prefix catalog_prefix, billed_month timestamptz) -returns jsonb as $$ -declare - -- Auth checks - has_admin_grant boolean; - has_bypassrls boolean; - - -- Output variables. - o_daily_usage jsonb; - o_data_gb numeric; - o_line_items jsonb = '[]'; - o_recurring_fee integer; - o_subtotal integer; - o_task_hours numeric; - o_trial_credit integer; - o_trial_start date; - o_trial_range daterange; - o_billed_range daterange; -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 the real active role has bypassrls flag set. - -- Because this function is SECURITY DEFINER, both `current_user` and `current_role` - -- will be `postgres`, which does have bypassrls set. Instead we want the - -- role of the caller, which can be accessed like so according to: - -- https://www.postgresql.org/message-id/13906.1141711109%40sss.pgh.pa.us - perform * from pg_roles where rolname = current_setting('role') and rolbypassrls = true; - has_bypassrls = found; - - if not has_admin_grant and not has_bypassrls 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; - - with vars as ( - select - t.data_tiers, - t.trial_start, - t.usage_tiers, - tstzrange(billed_month, billed_month + '1 month', '[)') as billed_range, - case when t.trial_start is not null - then tstzrange(t.trial_start, t.trial_start + interval '1 month', '[)') - else 'empty' end as trial_range, - -- Reveal contract costs only when computing whole-tenant billing. - case when t.tenant = billed_prefix then t.recurring_usd_cents else 0 end as recurring_fee - from tenants t - where billed_prefix ^@ t.tenant -- Prefix starts with tenant. - ), - -- Roll up each day's incremental usage. - daily_stat_deltas as ( - select - ts, - sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024) as data_gb, - sum(usage_seconds) / (60.0 * 60) as task_hours - from catalog_stats, vars - where catalog_name ^@ billed_prefix -- Name starts with prefix. - and grain = 'daily' - and billed_range @> ts - group by ts - ), - -- Map to cumulative daily usage. - -- Note sum(...) over (order by ts) yields the running sum of its aggregate. - daily_stats as ( - select - ts, - sum(data_gb) over w as data_gb, - sum(task_hours) over w as task_hours - from daily_stat_deltas - window w as (order by ts) - ), - -- Extend with line items for each category for the period ending with the given day. - daily_line_items as ( - select - daily_stats.*, - tier_line_items(data_gb, data_tiers, 'Data processing', 'GB') as data_line_items, - tier_line_items(task_hours, usage_tiers, 'Task usage', 'hour') as task_line_items - from daily_stats, vars - ), - -- Extend with per-category subtotals for the period ending with the given day. - daily_totals as ( - select - daily_line_items.*, - data_subtotal, - task_subtotal - from daily_line_items, - lateral (select sum((li->>'subtotal')::numeric) as data_subtotal from jsonb_array_elements(data_line_items) li) l1, - lateral (select sum((li->>'subtotal')::numeric) as task_subtotal from jsonb_array_elements(task_line_items) li) l2 - ), - -- Map cumulative totals to per-day deltas. - daily_deltas as ( - select - ts, - data_gb - (coalesce(lag(data_gb, 1) over w, 0)) as data_gb, - data_subtotal - (coalesce(lag(data_subtotal, 1) over w, 0)) as data_subtotal, - task_hours - (coalesce(lag(task_hours, 1) over w, 0)) as task_hours, - task_subtotal - (coalesce(lag(task_subtotal, 1) over w, 0)) as task_subtotal - from daily_totals - window w as (order by ts) - ), - -- 1) Group daily_deltas into a JSON array - -- 2) Sum a trial credit from daily deltas that overlap with the trial period. - daily_array_and_trial_credit as ( - select - jsonb_agg(jsonb_build_object( - 'ts', ts, - 'data_gb', data_gb, - 'data_subtotal', data_subtotal, - 'task_hours', task_hours, - 'task_subtotal', task_subtotal - )) as daily_usage, - coalesce(sum(data_subtotal + task_subtotal) filter (where trial_range @>ts),0 ) as trial_credit - from daily_deltas, vars - ), - -- The last day captures the cumulative billed period. - last_day as ( - select * from daily_line_items - order by ts desc limit 1 - ), - -- If we're reporting for the whole tenant then gather billing adjustment line-items. - adjustments as ( - select coalesce(jsonb_agg( - jsonb_build_object( - 'description', detail, - 'count', 1, - 'rate', usd_cents, - 'subtotal', usd_cents - ) - ), '[]') as adjustment_line_items - from internal.billing_adjustments a - where a.tenant = billed_prefix and a.billed_month = billing_report_202308.billed_month - ) - select into - -- Block of variables being selected into. - o_daily_usage, - o_data_gb, - o_line_items, - o_recurring_fee, - o_task_hours, - o_trial_credit, - o_trial_start, - o_trial_range, - o_billed_range - -- The actual selected columns. - daily_usage, - data_gb, - data_line_items || task_line_items || adjustment_line_items, - recurring_fee, - task_hours, - trial_credit, - trial_start, - trial_range, - billed_range - from daily_array_and_trial_credit, last_day, adjustments, vars; - - -- Add line items for recurring service fee & free trial credit. - if o_recurring_fee != 0 then - o_line_items = jsonb_build_object( - 'description', 'Recurring service charge', - 'count', 1, - 'rate', o_recurring_fee, - 'subtotal', o_recurring_fee - ) || o_line_items; - end if; - - -- Display a (possibly zero) free trial credit if the trial range overlaps the billed range - if o_trial_range && o_billed_range then - o_line_items = o_line_items || jsonb_build_object( - 'description', format('Free trial credit (%s - %s)', lower(o_trial_range), (upper(o_trial_range) - interval '1 day')::date), - 'count', 1, - 'rate', -o_trial_credit, - 'subtotal', -o_trial_credit - ); - end if; - - -- Roll up the final subtotal. - select into o_subtotal sum((l->>'subtotal')::numeric) - from jsonb_array_elements(o_line_items) l; - - return jsonb_build_object( - 'billed_month', billed_month, - 'billed_prefix', billed_prefix, - 'daily_usage', o_daily_usage, - 'line_items', o_line_items, - 'processed_data_gb', o_data_gb, - 'recurring_fee', o_recurring_fee, - 'subtotal', o_subtotal, - 'task_usage_hours', o_task_hours, - 'trial_credit', coalesce(o_trial_credit, 0), - 'trial_start', o_trial_start - ); - -end -$$ language plpgsql volatile security definer; - -commit; \ No newline at end of file diff --git a/supabase/migrations/29_round_free_trial.sql b/supabase/migrations/29_round_free_trial.sql deleted file mode 100644 index 8168a9e162..0000000000 --- a/supabase/migrations/29_round_free_trial.sql +++ /dev/null @@ -1,256 +0,0 @@ -begin; - --- Compute a JSONB array of line-items detailing usage under a tenant's effective tiers. -create or replace function tier_line_items( - -- Ammount of usage we're breaking out. - amount integer, - -- Effective tenant tiers as ordered pairs of (quantity, cents), followed - -- by a final unpaired cents for unbounded usage beyond the final quantity. - tiers integer[], - -- Descriptive name of the tiered thing ("Data processing"). - name text, - -- Unit of the tier ("GB" or "hour"). - unit text -) -returns jsonb as $$ -declare - o_line_items jsonb = '[]'; -- Output variable. - tier_count integer; - tier_pivot integer; - tier_rate integer; -begin - - for idx in 1..array_length(tiers, 1) by 2 loop - tier_rate = tiers[idx]; - tier_pivot = tiers[idx+1]; - tier_count = least(amount, tier_pivot); - amount = amount - tier_count; - - o_line_items = o_line_items || jsonb_build_object( - 'description', format( - case - when tier_pivot is null then '%1$s (at %4$s/%2$s)' -- Data processing (at $0.50/GB) - when idx = 1 then '%1s (first %3$s %2$ss at %4$s/%2$s)' -- Data processing (first 30 GBs at $0.50/GB) - else '%1$s (next %3$s %2$ss at %4$s/%2$s)' -- Data processing (next 6 GBs at $0.25/GB) - end, - name, - unit, - tier_pivot, - (tier_rate / 100.0)::money - ), - 'count', tier_count, - 'rate', tier_rate, - 'subtotal', tier_count * tier_rate - ); - end loop; - - return o_line_items; - -end -$$ language plpgsql; - - --- Billing report which is effective August 2023. -create or replace function billing_report_202308(billed_prefix catalog_prefix, billed_month timestamptz) -returns jsonb as $$ -declare - -- Auth checks - has_admin_grant boolean; - has_bypassrls boolean; - - -- Output variables. - o_daily_usage jsonb; - o_data_gb numeric; - o_line_items jsonb = '[]'; - o_recurring_fee integer; - o_subtotal integer; - o_task_hours numeric; - o_trial_credit integer; - o_trial_start date; - o_trial_range daterange; - o_billed_range daterange; -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 the real active role has bypassrls flag set. - -- Because this function is SECURITY DEFINER, both `current_user` and `current_role` - -- will be `postgres`, which does have bypassrls set. Instead we want the - -- role of the caller, which can be accessed like so according to: - -- https://www.postgresql.org/message-id/13906.1141711109%40sss.pgh.pa.us - perform * from pg_roles where rolname = current_setting('role') and rolbypassrls = true; - has_bypassrls = found; - - if not has_admin_grant and not has_bypassrls 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; - - with vars as ( - select - t.data_tiers, - t.trial_start, - t.usage_tiers, - tstzrange(billed_month, billed_month + '1 month', '[)') as billed_range, - case when t.trial_start is not null - then tstzrange(t.trial_start, t.trial_start + interval '1 month', '[)') - else 'empty' end as trial_range, - -- Reveal contract costs only when computing whole-tenant billing. - case when t.tenant = billed_prefix then t.recurring_usd_cents else 0 end as recurring_fee - from tenants t - where billed_prefix ^@ t.tenant -- Prefix starts with tenant. - ), - -- Roll up each day's incremental usage. - daily_stat_deltas as ( - select - ts, - sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024) as data_gb, - sum(usage_seconds) / (60.0 * 60) as task_hours - from catalog_stats, vars - where catalog_name ^@ billed_prefix -- Name starts with prefix. - and grain = 'daily' - and billed_range @> ts - group by ts - ), - -- Map to cumulative daily usage. - -- Note sum(...) over (order by ts) yields the running sum of its aggregate. - daily_stats as ( - select - ts, - sum(data_gb) over w as data_gb, - sum(task_hours) over w as task_hours - from daily_stat_deltas - window w as (order by ts) - ), - -- Extend with line items for each category for the period ending with the given day. - daily_line_items as ( - select - daily_stats.*, - tier_line_items(ceil(data_gb), data_tiers, 'Data processing', 'GB') as data_line_items, - tier_line_items(ceil(task_hours), usage_tiers, 'Task usage', 'hour') as task_line_items - from daily_stats, vars - ), - -- Extend with per-category subtotals for the period ending with the given day. - daily_totals as ( - select - daily_line_items.*, - data_subtotal, - task_subtotal - from daily_line_items, - lateral (select sum((li->>'subtotal')::numeric) as data_subtotal from jsonb_array_elements(data_line_items) li) l1, - lateral (select sum((li->>'subtotal')::numeric) as task_subtotal from jsonb_array_elements(task_line_items) li) l2 - ), - -- Map cumulative totals to per-day deltas. - daily_deltas as ( - select - ts, - data_gb - (coalesce(lag(data_gb, 1) over w, 0)) as data_gb, - data_subtotal - (coalesce(lag(data_subtotal, 1) over w, 0)) as data_subtotal, - task_hours - (coalesce(lag(task_hours, 1) over w, 0)) as task_hours, - task_subtotal - (coalesce(lag(task_subtotal, 1) over w, 0)) as task_subtotal - from daily_totals - window w as (order by ts) - ), - -- 1) Group daily_deltas into a JSON array - -- 2) Sum a trial credit from daily deltas that overlap with the trial period. - daily_array_and_trial_credit as ( - select - jsonb_agg(jsonb_build_object( - 'ts', ts, - 'data_gb', data_gb, - 'data_subtotal', data_subtotal, - 'task_hours', task_hours, - 'task_subtotal', task_subtotal - )) as daily_usage, - coalesce(sum(data_subtotal + task_subtotal) filter (where trial_range @>ts),0 ) as trial_credit - from daily_deltas, vars - ), - -- The last day captures the cumulative billed period. - last_day as ( - select * from daily_line_items - order by ts desc limit 1 - ), - -- If we're reporting for the whole tenant then gather billing adjustment line-items. - adjustments as ( - select coalesce(jsonb_agg( - jsonb_build_object( - 'description', detail, - 'count', 1, - 'rate', usd_cents, - 'subtotal', usd_cents - ) - ), '[]') as adjustment_line_items - from internal.billing_adjustments a - where a.tenant = billed_prefix and a.billed_month = billing_report_202308.billed_month - ) - select into - -- Block of variables being selected into. - o_daily_usage, - o_data_gb, - o_line_items, - o_recurring_fee, - o_task_hours, - o_trial_credit, - o_trial_start, - o_trial_range, - o_billed_range - -- The actual selected columns. - daily_usage, - data_gb, - data_line_items || task_line_items || adjustment_line_items, - recurring_fee, - task_hours, - trial_credit, - trial_start, - trial_range, - billed_range - from daily_array_and_trial_credit, last_day, adjustments, vars; - - -- Add line items for recurring service fee & free trial credit. - if o_recurring_fee != 0 then - o_line_items = jsonb_build_object( - 'description', 'Recurring service charge', - 'count', 1, - 'rate', o_recurring_fee, - 'subtotal', o_recurring_fee - ) || o_line_items; - end if; - - -- Display a (possibly zero) free trial credit if the trial range overlaps the billed range - if o_trial_range && o_billed_range then - o_line_items = o_line_items || jsonb_build_object( - 'description', format('Free trial credit (%s - %s)', lower(o_trial_range), (upper(o_trial_range) - interval '1 day')::date), - 'count', 1, - 'rate', -o_trial_credit, - 'subtotal', -o_trial_credit - ); - end if; - - -- Roll up the final subtotal. - select into o_subtotal sum((l->>'subtotal')::numeric) - from jsonb_array_elements(o_line_items) l; - - return jsonb_build_object( - 'billed_month', billed_month, - 'billed_prefix', billed_prefix, - 'daily_usage', o_daily_usage, - 'line_items', o_line_items, - 'processed_data_gb', o_data_gb, - 'recurring_fee', o_recurring_fee, - 'subtotal', o_subtotal, - 'task_usage_hours', o_task_hours, - 'trial_credit', coalesce(o_trial_credit, 0), - 'trial_start', o_trial_start - ); - -end -$$ language plpgsql volatile security definer; - -commit; \ No newline at end of file diff --git a/supabase/migrations/30_log_lines_index.sql b/supabase/migrations/30_log_lines_index.sql deleted file mode 100644 index c7f1fcab0f..0000000000 --- a/supabase/migrations/30_log_lines_index.sql +++ /dev/null @@ -1,11 +0,0 @@ - --- The previous BRIN index on internal.log_lines is ineffective for queries that don't --- supply a where condition on the `logged_at` timestamp. Currently, that represents --- all queries against that table. This drops the old BRIN index in favor of a regular --- btree index, which is effective when queries only provide the `token`. - -begin; -create index idx_logs_token on internal.log_lines (token); -drop index internal.idx_logs_token_logged_at; -commit; - diff --git a/supabase/migrations/31_manual_billing.sql b/supabase/migrations/31_manual_billing.sql deleted file mode 100644 index 09a6727b37..0000000000 --- a/supabase/migrations/31_manual_billing.sql +++ /dev/null @@ -1,359 +0,0 @@ -begin; - -create table internal.manual_bills ( - tenant catalog_tenant not null references tenants(tenant), - usd_cents integer not null, - description text not null, - date_start date not null, - date_end date not null, - constraint dates_make_sense check (date_start < date_end), - primary key (tenant, date_start, date_end) -); - -comment on table internal.manual_bills is - 'Manually entered bills that span an arbitrary date range'; - --- Move billing report gen to internal - --- Drop the public functions -drop function billing_report_202308(catalog_prefix, timestamptz); -drop function tier_line_items(integer, integer[], text, text); - --- Move `billing_historicals` to internal and revoke access -alter table billing_historicals disable row level security; -drop policy "Users must be authorized to their catalog tenant" on billing_historicals; - -revoke select on billing_historicals from authenticated; -alter table billing_historicals set schema internal; - --- Compute a JSONB array of line-items detailing usage under a tenant's effective tiers. -create or replace function internal.tier_line_items( - -- Ammount of usage we're breaking out. - amount integer, - -- Effective tenant tiers as ordered pairs of (quantity, cents), followed - -- by a final unpaired cents for unbounded usage beyond the final quantity. - tiers integer[], - -- Descriptive name of the tiered thing ("Data processing"). - name text, - -- Unit of the tier ("GB" or "hour"). - unit text -) -returns jsonb as $$ -declare - o_line_items jsonb = '[]'; -- Output variable. - tier_count integer; - tier_pivot integer; - tier_rate integer; -begin - - for idx in 1..array_length(tiers, 1) by 2 loop - tier_rate = tiers[idx]; - tier_pivot = tiers[idx+1]; - tier_count = least(amount, tier_pivot); - amount = amount - tier_count; - - o_line_items = o_line_items || jsonb_build_object( - 'description', format( - case - when tier_pivot is null then '%1$s (at %4$s/%2$s)' -- Data processing (at $0.50/GB) - when idx = 1 then '%1s (first %3$s %2$ss at %4$s/%2$s)' -- Data processing (first 30 GBs at $0.50/GB) - else '%1$s (next %3$s %2$ss at %4$s/%2$s)' -- Data processing (next 6 GBs at $0.25/GB) - end, - name, - unit, - tier_pivot, - (tier_rate / 100.0)::money - ), - 'count', tier_count, - 'rate', tier_rate, - 'subtotal', tier_count * tier_rate - ); - end loop; - - return o_line_items; - -end -$$ language plpgsql; - - --- Billing report which is effective August 2023. --- Removed authorization logic as it's now going to be handled in invoices_ext -create or replace function internal.billing_report_202308(billed_prefix catalog_prefix, billed_month timestamptz) -returns jsonb as $$ -declare - -- Output variables. - o_daily_usage jsonb; - o_data_gb numeric; - o_line_items jsonb = '[]'; - o_recurring_fee integer; - o_subtotal integer; - o_task_hours numeric; - o_trial_credit integer; - o_trial_start date; - o_trial_range daterange; - o_billed_range daterange; -begin - - -- Ensure `billed_month` is the truncated start of the billed month. - billed_month = date_trunc('month', billed_month); - - with vars as ( - select - t.data_tiers, - t.trial_start, - t.usage_tiers, - tstzrange(billed_month, billed_month + '1 month', '[)') as billed_range, - case when t.trial_start is not null - then tstzrange(t.trial_start, t.trial_start + interval '1 month', '[)') - else 'empty' end as trial_range, - -- Reveal contract costs only when computing whole-tenant billing. - case when t.tenant = billed_prefix then t.recurring_usd_cents else 0 end as recurring_fee - from tenants t - where billed_prefix ^@ t.tenant -- Prefix starts with tenant. - ), - -- Roll up each day's incremental usage. - daily_stat_deltas as ( - select - ts, - sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024) as data_gb, - sum(usage_seconds) / (60.0 * 60) as task_hours - from catalog_stats, vars - where catalog_name ^@ billed_prefix -- Name starts with prefix. - and grain = 'daily' - and billed_range @> ts - group by ts - ), - -- Map to cumulative daily usage. - -- Note sum(...) over (order by ts) yields the running sum of its aggregate. - daily_stats as ( - select - ts, - sum(data_gb) over w as data_gb, - sum(task_hours) over w as task_hours - from daily_stat_deltas - window w as (order by ts) - ), - -- Extend with line items for each category for the period ending with the given day. - daily_line_items as ( - select - daily_stats.*, - internal.tier_line_items(ceil(data_gb)::integer, data_tiers, 'Data processing', 'GB') as data_line_items, - internal.tier_line_items(ceil(task_hours)::integer, usage_tiers, 'Task usage', 'hour') as task_line_items - from daily_stats, vars - ), - -- Extend with per-category subtotals for the period ending with the given day. - daily_totals as ( - select - daily_line_items.*, - data_subtotal, - task_subtotal - from daily_line_items, - lateral (select sum((li->>'subtotal')::numeric) as data_subtotal from jsonb_array_elements(data_line_items) li) l1, - lateral (select sum((li->>'subtotal')::numeric) as task_subtotal from jsonb_array_elements(task_line_items) li) l2 - ), - -- Map cumulative totals to per-day deltas. - daily_deltas as ( - select - ts, - data_gb - (coalesce(lag(data_gb, 1) over w, 0)) as data_gb, - data_subtotal - (coalesce(lag(data_subtotal, 1) over w, 0)) as data_subtotal, - task_hours - (coalesce(lag(task_hours, 1) over w, 0)) as task_hours, - task_subtotal - (coalesce(lag(task_subtotal, 1) over w, 0)) as task_subtotal - from daily_totals - window w as (order by ts) - ), - -- 1) Group daily_deltas into a JSON array - -- 2) Sum a trial credit from daily deltas that overlap with the trial period. - daily_array_and_trial_credit as ( - select - jsonb_agg(jsonb_build_object( - 'ts', ts, - 'data_gb', data_gb, - 'data_subtotal', data_subtotal, - 'task_hours', task_hours, - 'task_subtotal', task_subtotal - )) as daily_usage, - coalesce(sum(data_subtotal + task_subtotal) filter (where trial_range @>ts),0 ) as trial_credit - from daily_deltas, vars - ), - -- The last day captures the cumulative billed period. - last_day as ( - select * from daily_line_items - order by ts desc limit 1 - ), - -- If we're reporting for the whole tenant then gather billing adjustment line-items. - adjustments as ( - select coalesce(jsonb_agg( - jsonb_build_object( - 'description', detail, - 'count', 1, - 'rate', usd_cents, - 'subtotal', usd_cents - ) - ), '[]') as adjustment_line_items - from internal.billing_adjustments a - where a.tenant = billed_prefix and a.billed_month = billing_report_202308.billed_month - ) - select into - -- Block of variables being selected into. - o_daily_usage, - o_data_gb, - o_line_items, - o_recurring_fee, - o_task_hours, - o_trial_credit, - o_trial_start, - o_trial_range, - o_billed_range - -- The actual selected columns. - daily_usage, - data_gb, - data_line_items || task_line_items || adjustment_line_items, - recurring_fee, - task_hours, - trial_credit, - trial_start, - trial_range, - billed_range - from daily_array_and_trial_credit, last_day, adjustments, vars; - - -- Add line items for recurring service fee & free trial credit. - if o_recurring_fee != 0 then - o_line_items = jsonb_build_object( - 'description', 'Recurring service charge', - 'count', 1, - 'rate', o_recurring_fee, - 'subtotal', o_recurring_fee - ) || o_line_items; - end if; - - -- Display a (possibly zero) free trial credit if the trial range overlaps the billed range - if o_trial_range && o_billed_range then - o_line_items = o_line_items || jsonb_build_object( - 'description', format('Free trial credit (%s - %s)', lower(o_trial_range), (upper(o_trial_range) - interval '1 day')::date), - 'count', 1, - 'rate', -o_trial_credit, - 'subtotal', -o_trial_credit - ); - end if; - - -- Roll up the final subtotal. - select into o_subtotal sum((l->>'subtotal')::numeric) - from jsonb_array_elements(o_line_items) l; - - return jsonb_build_object( - 'billed_month', billed_month, - 'billed_prefix', billed_prefix, - 'daily_usage', o_daily_usage, - 'line_items', o_line_items, - 'processed_data_gb', o_data_gb, - 'recurring_fee', o_recurring_fee, - 'subtotal', o_subtotal, - 'task_usage_hours', o_task_hours, - 'trial_credit', coalesce(o_trial_credit, 0), - 'trial_start', o_trial_start - ); - -end -$$ language plpgsql volatile security definer; - --- Note: have to redefine this to know about internal.billing_report --- Calculate the specified month's billing report for every tenant --- and save those reports to billing_historicals. -create or replace 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 internal.billing_historicals - select - report->>'billed_prefix' as tenant, - (report->>'billed_month')::timestamptz as billed_month, - report - from internal.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; --- End internal billing report gen - -create or replace view invoices_ext as -with has_bypassrls as ( - select exists(select 1 from pg_roles where rolname = current_role and rolbypassrls = true) as bypass -), -authorized_tenants as ( - select tenants.tenant, tenants.created_at - from tenants - left join has_bypassrls on true - left join auth_roles('admin') on tenants.tenant ^@ auth_roles.role_prefix - where has_bypassrls.bypass or auth_roles.role_prefix is not null -), -historical_bills as ( - select - date_trunc('month', (report->>'billed_month')::timestamptz)::date as date_start, - (date_trunc('month', (report->>'billed_month')::timestamptz) + interval '1 month' - interval '1 day')::date as date_end, - report->>'billed_prefix' as billed_prefix, - coalesce(nullif(report->'line_items', 'null'::jsonb), '[]'::jsonb) as line_items, - coalesce(nullif(report->'subtotal', 'null'::jsonb), to_jsonb(0))::integer as subtotal, - report as extra - from internal.billing_historicals - -- inner join should give only rows that match the join condition - inner join authorized_tenants on billing_historicals.tenant ^@ authorized_tenants.tenant -), -manual_bills as ( - select - date_start, - date_end, - manual_bills.tenant as billed_prefix, - jsonb_build_array( - jsonb_build_object( - 'description', manual_bills.description, - 'count', 1, - 'rate', manual_bills.usd_cents, - 'subtotal', manual_bills.usd_cents - ) - ) as line_items, - usd_cents as subtotal, - 'null'::jsonb as extra - from internal.manual_bills - inner join authorized_tenants on manual_bills.tenant ^@ authorized_tenants.tenant -), -generated_prior_months as ( - select - date_trunc('month', (report->>'billed_month')::timestamptz)::date as date_start, - (date_trunc('month', (report->>'billed_month')::timestamptz) + interval '1 month' - interval '1 day')::date as date_end, - report->>'billed_prefix' as billed_prefix, - coalesce(nullif(report->'line_items', 'null'::jsonb), '[]'::jsonb) as line_items, - coalesce(nullif(report->'subtotal', 'null'::jsonb), to_jsonb(0))::integer as subtotal, - report as extra - from authorized_tenants - join generate_series( - greatest(date '2023-08-01', date_trunc('month', authorized_tenants.created_at)::date), - date_trunc('month',now()::date), - '1 month' - ) as invoice_month on not exists(select 1 from historical_bills where historical_bills.date_start = invoice_month) - join internal.billing_report_202308(authorized_tenants.tenant, invoice_month) as report on true -) -select - h.date_start, h.date_end, h.billed_prefix, h.line_items, h.subtotal, h.extra, 'final' as invoice_type -from historical_bills h -union all -select - p.date_start, p.date_end, p.billed_prefix, p.line_items, p.subtotal, p.extra, 'preview' as invoice_type -from generated_prior_months p -union all -select - m.date_start, m.date_end, m.billed_prefix, m.line_items, m.subtotal, m.extra, 'manual' as invoice_type -from manual_bills m; - -grant select on table invoices_ext to authenticated; - -commit; \ No newline at end of file diff --git a/supabase/migrations/32_invoices_ext_perf.sql b/supabase/migrations/32_invoices_ext_perf.sql deleted file mode 100644 index b31c1adf96..0000000000 --- a/supabase/migrations/32_invoices_ext_perf.sql +++ /dev/null @@ -1,71 +0,0 @@ -begin; - --- Refactor this to avoid use of CTEs, which don't support predicate push-down, --- which was causing query performance to be very bad. --- This is essentially the same as the existing invoices_ext, except the three --- different invoice types are now computed in subqueries instead of CTEs. The other --- change is to select authorized_tenants.tenant as the billed_prefix, which allows --- a filter on invoices_ext.billed_prefix to get pushed down properly. -create or replace view invoices_ext as -with has_bypassrls as ( - select exists(select 1 from pg_roles where rolname = current_role and rolbypassrls = true) as bypass -), -authorized_tenants as ( - select tenants.tenant, tenants.created_at - from tenants - left join has_bypassrls on true - left join auth_roles('admin') on tenants.tenant ^@ auth_roles.role_prefix - where has_bypassrls.bypass or auth_roles.role_prefix is not null -) -select - date_trunc('month', (report->>'billed_month')::timestamptz)::date as date_start, - (date_trunc('month', (report->>'billed_month')::timestamptz) + interval '1 month' - interval '1 day')::date as date_end, - authorized_tenants.tenant::text as billed_prefix, - coalesce(nullif(report->'line_items', 'null'::jsonb), '[]'::jsonb) as line_items, - coalesce(nullif(report->'subtotal', 'null'::jsonb), to_jsonb(0))::integer as subtotal, - report as extra, - 'final' as invoice_type - from internal.billing_historicals h - -- inner join should give only rows that match the join condition - inner join authorized_tenants on h.tenant ^@ authorized_tenants.tenant -union all -select - date_trunc('month', (report->>'billed_month')::timestamptz)::date as date_start, - (date_trunc('month', (report->>'billed_month')::timestamptz) + interval '1 month' - interval '1 day')::date as date_end, - authorized_tenants.tenant::text as billed_prefix, - coalesce(nullif(report->'line_items', 'null'::jsonb), '[]'::jsonb) as line_items, - coalesce(nullif(report->'subtotal', 'null'::jsonb), to_jsonb(0))::integer as subtotal, - report as extra, - 'preview' as invoice_type - from authorized_tenants - join generate_series( - greatest(date '2023-08-01', date_trunc('month', authorized_tenants.created_at)::date), - date_trunc('month',now()::date), - '1 month' - ) as invoice_month on not exists( - select 1 - from internal.billing_historicals h - where h.tenant ^@ authorized_tenants.tenant - and date_trunc('month', (h.report->>'billed_month')::timestamptz)::date = invoice_month - ) - join internal.billing_report_202308(authorized_tenants.tenant, invoice_month) as report on true -union all -select - date_start, - date_end, - authorized_tenants.tenant::text as billed_prefix, - jsonb_build_array( - jsonb_build_object( - 'description', manual_bills.description, - 'count', 1, - 'rate', manual_bills.usd_cents, - 'subtotal', manual_bills.usd_cents - ) - ) as line_items, - usd_cents as subtotal, - 'null'::jsonb as extra, - 'manual' as invoice_type - from internal.manual_bills - inner join authorized_tenants on manual_bills.tenant ^@ authorized_tenants.tenant; - -commit; \ No newline at end of file diff --git a/supabase/migrations/33_automate_trial_start.sql b/supabase/migrations/33_automate_trial_start.sql deleted file mode 100644 index 09d884be73..0000000000 --- a/supabase/migrations/33_automate_trial_start.sql +++ /dev/null @@ -1,82 +0,0 @@ -begin; - --- Index that accelerates operator ^@ (starts-with) for catalog_stats and friends. -create index catalog_stats_catalog_index_spgist on catalog_stats using spgist ((catalog_name::text)); - -create or replace view internal.new_free_trial_tenants as -with hours_by_day as ( - select - tenants.tenant as tenant, - ts, - sum(catalog_stats_daily.usage_seconds / (60.0 * 60)) as daily_usage_hours - from catalog_stats_daily - join tenants on catalog_stats_daily.catalog_name ^@ tenants.tenant - where tenants.trial_start is null - group by tenants.tenant, ts - having sum(catalog_stats_daily.usage_seconds / (60.0 * 60)) > (2 * 24) -), -hours_by_month as ( - select - tenants.tenant as tenant, - ts, - sum(catalog_stats_monthly.usage_seconds / (60.0 * 60)) as monthly_usage_hours - from catalog_stats_monthly - join tenants on catalog_stats_monthly.catalog_name ^@ tenants.tenant - where tenants.trial_start is null - group by tenants.tenant, ts - having sum(catalog_stats_monthly.usage_seconds / (60.0 * 60)) > (24 * 31 * 2) -), -gbs_by_month as ( - select - tenants.tenant as tenant, - ts, - ceil(sum((catalog_stats_monthly.bytes_written_by_me + catalog_stats_monthly.bytes_read_by_me) / (1024.0 * 1024 * 1024))) as monthly_usage_gbs - from catalog_stats_monthly - join tenants on catalog_stats_monthly.catalog_name ^@ tenants.tenant - where tenants.trial_start is null - group by tenants.tenant, ts - having ceil(sum((catalog_stats_monthly.bytes_written_by_me + catalog_stats_monthly.bytes_read_by_me) / (1024.0 * 1024 * 1024))) > 10 -) -select - tenants.tenant as tenant, - max(hours_by_day.daily_usage_hours) as max_daily_usage_hours, - max(hours_by_month.monthly_usage_hours) as max_monthly_usage_hours, - max(gbs_by_month.monthly_usage_gbs) as max_monthly_gb, - count(distinct live_specs.id) filter (where live_specs.spec_type = 'capture') as today_captures, - count(distinct live_specs.id) filter (where live_specs.spec_type = 'materialization') as today_materializations -from tenants -left join hours_by_day on hours_by_day.tenant = tenants.tenant -left join hours_by_month on hours_by_month.tenant = tenants.tenant -left join gbs_by_month on gbs_by_month.tenant = tenants.tenant -join live_specs on (split_part(live_specs.catalog_name,'/',1)||'/' = tenants.tenant and (live_specs.spec #>> '{shards,disable}')::boolean is not true) -where tenants.trial_start is null -group by tenants.tenant -having count(hours_by_month) > 0 or count(hours_by_day) > 0 or count(gbs_by_month) > 0; - -create or replace function internal.set_new_free_trials() -returns integer as $$ -declare - tenant_row record; - update_count integer = 0; -begin - for tenant_row in select tenant from internal.new_free_trial_tenants loop - update tenants set trial_start = date_trunc('day', now()) - where tenants.tenant = tenant_row.tenant; - - -- INSERT statements set FOUND true if at least one row is affected, false if no row is affected. - if found then - update_count = update_count + 1; - end if; - end loop; - return update_count; -end -$$ language plpgsql volatile; - -create extension if not exists pg_cron with schema extensions; -select cron.schedule( - 'free-trials', -- name of the cron job - '0 05 * * *', -- Every day at 05:00Z - $$ select internal.set_new_free_trials() $$ -); - -commit; \ No newline at end of file diff --git a/supabase/migrations/34_tenants_pay_externally.sql b/supabase/migrations/34_tenants_pay_externally.sql deleted file mode 100644 index f1c80eb683..0000000000 --- a/supabase/migrations/34_tenants_pay_externally.sql +++ /dev/null @@ -1,14 +0,0 @@ -begin; - -create type payment_provider_type as enum ( - 'stripe', - 'external' -); - -comment on type payment_provider_type is ' -Enumeration of which payment provider this tenant is using. -'; - -alter table tenants add column "payment_provider" payment_provider_type default 'stripe'; - -commit; diff --git a/supabase/migrations/35_free_tier_credit.sql b/supabase/migrations/35_free_tier_credit.sql deleted file mode 100644 index cbb153aaa0..0000000000 --- a/supabase/migrations/35_free_tier_credit.sql +++ /dev/null @@ -1,209 +0,0 @@ -begin; - --- Billing report which is effective August 2023. --- Removed authorization logic as it's now going to be handled in invoices_ext -create or replace function internal.billing_report_202308(billed_prefix catalog_prefix, billed_month timestamptz) -returns jsonb as $$ -declare - -- Output variables. - o_daily_usage jsonb; - o_data_gb numeric; - o_line_items jsonb = '[]'; - o_recurring_fee integer; - o_subtotal integer; - o_task_hours numeric; - o_trial_credit integer; - o_free_tier_credit integer; - o_trial_start date; - o_trial_range daterange; - o_free_tier_range daterange; - o_billed_range daterange; -begin - - -- Ensure `billed_month` is the truncated start of the billed month. - billed_month = date_trunc('month', billed_month); - - with vars as ( - select - t.data_tiers, - t.trial_start, - t.usage_tiers, - tstzrange(billed_month, billed_month + '1 month', '[)') as billed_range, - case when t.trial_start is not null - then daterange(t.trial_start::date, ((t.trial_start::date) + interval '1 month')::date, '[)') - else 'empty' end as trial_range, - -- In order to smoothly transition between free tier credit and free trial credit, - -- the free tier covers all usage up to, but _not including_ the trial start date. - -- On the trial start date, the free trial credit takes over. - daterange(NULL, t.trial_start::date, '[)') as free_tier_range, - -- Reveal contract costs only when computing whole-tenant billing. - case when t.tenant = billed_prefix then t.recurring_usd_cents else 0 end as recurring_fee - from tenants t - where billed_prefix ^@ t.tenant -- Prefix starts with tenant. - ), - -- Roll up each day's incremental usage. - daily_stat_deltas as ( - select - ts, - sum(bytes_written_by_me + bytes_read_by_me) / (1024.0 * 1024 * 1024) as data_gb, - sum(usage_seconds) / (60.0 * 60) as task_hours - from catalog_stats, vars - where catalog_name ^@ billed_prefix -- Name starts with prefix. - and grain = 'daily' - and billed_range @> ts - group by ts - ), - -- Map to cumulative daily usage. - -- Note sum(...) over (order by ts) yields the running sum of its aggregate. - daily_stats as ( - select - ts, - sum(data_gb) over w as data_gb, - sum(task_hours) over w as task_hours - from daily_stat_deltas - window w as (order by ts) - ), - -- Extend with line items for each category for the period ending with the given day. - daily_line_items as ( - select - daily_stats.*, - internal.tier_line_items(ceil(data_gb)::integer, data_tiers, 'Data processing', 'GB') as data_line_items, - internal.tier_line_items(ceil(task_hours)::integer, usage_tiers, 'Task usage', 'hour') as task_line_items - from daily_stats, vars - ), - -- Extend with per-category subtotals for the period ending with the given day. - daily_totals as ( - select - daily_line_items.*, - data_subtotal, - task_subtotal - from daily_line_items, - lateral (select sum((li->>'subtotal')::numeric) as data_subtotal from jsonb_array_elements(data_line_items) li) l1, - lateral (select sum((li->>'subtotal')::numeric) as task_subtotal from jsonb_array_elements(task_line_items) li) l2 - ), - -- Map cumulative totals to per-day deltas. - daily_deltas as ( - select - ts, - data_gb - (coalesce(lag(data_gb, 1) over w, 0)) as data_gb, - data_subtotal - (coalesce(lag(data_subtotal, 1) over w, 0)) as data_subtotal, - task_hours - (coalesce(lag(task_hours, 1) over w, 0)) as task_hours, - task_subtotal - (coalesce(lag(task_subtotal, 1) over w, 0)) as task_subtotal - from daily_totals - window w as (order by ts) - ), - -- 1) Group daily_deltas into a JSON array - -- 2) Sum a trial credit from daily deltas that overlap with the trial period. - daily_array_and_trial_credits as ( - select - jsonb_agg(jsonb_build_object( - 'ts', ts, - 'data_gb', data_gb, - 'data_subtotal', data_subtotal, - 'task_hours', task_hours, - 'task_subtotal', task_subtotal - )) as daily_usage, - coalesce(sum(data_subtotal + task_subtotal) filter (where trial_range @> (ts::date)),0 ) as trial_credit, - coalesce(sum(data_subtotal + task_subtotal) filter (where free_tier_range @> (ts::date)),0 ) as free_tier_credit - from daily_deltas, vars - ), - -- The last day captures the cumulative billed period. - last_day as ( - select * from daily_line_items - order by ts desc limit 1 - ), - -- If we're reporting for the whole tenant then gather billing adjustment line-items. - adjustments as ( - select coalesce(jsonb_agg( - jsonb_build_object( - 'description', detail, - 'count', 1, - 'rate', usd_cents, - 'subtotal', usd_cents - ) - ), '[]') as adjustment_line_items - from internal.billing_adjustments a - where a.tenant = billed_prefix and a.billed_month = billing_report_202308.billed_month - ) - select into - -- Block of variables being selected into. - o_daily_usage, - o_data_gb, - o_line_items, - o_recurring_fee, - o_task_hours, - o_trial_credit, - o_trial_start, - o_trial_range, - o_billed_range, - o_free_tier_credit, - o_free_tier_range - -- The actual selected columns. - daily_usage, - data_gb, - data_line_items || task_line_items || adjustment_line_items, - recurring_fee, - task_hours, - trial_credit, - trial_start, - trial_range, - billed_range, - free_tier_credit, - free_tier_range - from daily_array_and_trial_credits, last_day, adjustments, vars; - - -- Add line items for recurring service fee & free trial credit. - if o_recurring_fee != 0 then - o_line_items = jsonb_build_object( - 'description', 'Recurring service charge', - 'count', 1, - 'rate', o_recurring_fee, - 'subtotal', o_recurring_fee - ) || o_line_items; - end if; - - -- Display a (possibly zero) free trial credit if the trial range overlaps the billed range - if o_trial_range && o_billed_range then - o_line_items = o_line_items || jsonb_build_object( - 'description', format('Free trial credit (%s - %s)', lower(o_trial_range), (upper(o_trial_range) - interval '1 day')::date), - 'count', 1, - 'rate', -o_trial_credit, - 'subtotal', -o_trial_credit - ); - end if; - - -- Display the free tier credit if the free tier range overlaps the billed range - if o_free_tier_range && o_billed_range then - o_line_items = o_line_items || jsonb_build_object( - 'description', case when upper(o_free_tier_range) is not null - then format('Free tier credit ending %s', (upper(o_free_tier_range) - interval '1 day')::date) - else 'Free tier credit' - end, - 'count', 1, - 'rate', -o_free_tier_credit, - 'subtotal', -o_free_tier_credit - ); - end if; - - -- Roll up the final subtotal. - select into o_subtotal sum((l->>'subtotal')::numeric) - from jsonb_array_elements(o_line_items) l; - - return jsonb_build_object( - 'billed_month', billed_month, - 'billed_prefix', billed_prefix, - 'daily_usage', o_daily_usage, - 'line_items', o_line_items, - 'processed_data_gb', o_data_gb, - 'recurring_fee', o_recurring_fee, - 'subtotal', o_subtotal, - 'task_usage_hours', o_task_hours, - 'trial_credit', coalesce(o_trial_credit, 0), - 'free_tier_credit', coalesce(o_free_tier_credit, 0), - 'trial_start', o_trial_start - ); - -end -$$ language plpgsql volatile security definer; - -commit; \ No newline at end of file diff --git a/supabase/migrations/36_prune_unchanged_draft_specs.sql b/supabase/migrations/36_prune_unchanged_draft_specs.sql deleted file mode 100644 index d17cd6fa82..0000000000 --- a/supabase/migrations/36_prune_unchanged_draft_specs.sql +++ /dev/null @@ -1,141 +0,0 @@ - -begin; - -alter table inferred_schemas add column "md5" text generated always as (md5(trim("schema"::text))) stored; -comment on column inferred_schemas.md5 is - 'hash of the inferred schema json, which is used to identify changes'; - -alter table live_specs add column inferred_schema_md5 text; -comment on column live_specs.inferred_schema_md5 is - 'The md5 sum of the inferred schema that was published with this spec'; - --- Re-define the live_specs_ext view to include the inferred_schema_md5 column, --- which will be needed by the unchanged_draft_specs view. Drop and re-create --- the views because selecting * changes the order of some columns. -drop view draft_specs_ext; -drop view live_specs_ext; - --- l.* expands to an additional column now, but columns are otherwise identical to the previous view definition --- Extended view of live catalog specifications. -create view live_specs_ext as -select - l.*, - c.external_url as connector_external_url, - c.id as connector_id, - c.title as connector_title, - c.short_description as connector_short_description, - c.logo_url as connector_logo_url, - c.recommended as connector_recommended, - t.id as connector_tag_id, - t.documentation_url as connector_tag_documentation_url, - p.detail as last_pub_detail, - p.user_id as last_pub_user_id, - u.avatar_url as last_pub_user_avatar_url, - u.email as last_pub_user_email, - u.full_name as last_pub_user_full_name -from live_specs l -left outer join publication_specs p on l.id = p.live_spec_id and l.last_pub_id = p.pub_id -left outer join connectors c on c.image_name = l.connector_image_name -left outer join connector_tags t on c.id = t.connector_id and l.connector_image_tag = t.image_tag -left outer join internal.user_profiles u on u.user_id = p.user_id --- This first condition allows superusers to query the view. The second is the normal RLS policy, --- but implemented here in a way that is more efficient when querying for large sets of specs. -where exists(select 1 from pg_roles where rolname = current_role and rolbypassrls = true) - or l.id in ( - -- User must be able to read catalog_name. Compare to select RLS policy. - select l.id from auth_roles('read') r, live_specs l - where l.catalog_name ^@ r.role_prefix - ) -; --- live_specs_ext includes its own authorization checks. -grant select on live_specs_ext to authenticated; - -comment on view live_specs_ext is - 'View of `live_specs` extended with metadata of its last publication'; - --- Extended view of user draft specifications. -create view draft_specs_ext as -select - d.*, - l.last_pub_detail, - l.last_pub_id, - l.last_pub_user_id, - l.last_pub_user_avatar_url, - l.last_pub_user_email, - l.last_pub_user_full_name, - l.spec as live_spec, - l.spec_type as live_spec_type, - -- new columns below - s.md5 as inferred_schema_md5, - l.inferred_schema_md5 as live_inferred_schema_md5, - l.md5 as live_spec_md5, - md5(trim(d.spec::text)) as draft_spec_md5 -from draft_specs d -left outer join live_specs_ext l - on d.catalog_name = l.catalog_name -left outer join inferred_schemas s - on s.collection_name = l.catalog_name -where exists(select 1 from pg_roles where rolname = current_role and rolbypassrls = true) - or d.draft_id in (select id from drafts where user_id = auth.uid()) -; -grant select on draft_specs_ext to authenticated; - -comment on view draft_specs_ext is - 'View of `draft_specs` extended with metadata of its live specification'; - -create view unchanged_draft_specs as - select - draft_id, - catalog_name, - spec_type, - live_spec_md5, - draft_spec_md5, - inferred_schema_md5, - live_inferred_schema_md5 - from draft_specs_ext d - where draft_spec_md5 = live_spec_md5 - and ( - -- either it's not a collection or it doesn't use the inferred schema - (spec_type != 'collection' or spec::text not like '%flow://inferred-schema%') - -- or the inferred schema hasn't changed since the last publication - or inferred_schema_md5 is not distinct from live_inferred_schema_md5 - ); -grant select on unchanged_draft_specs to authenticated; -comment on view unchanged_draft_specs is - 'View of `draft_specs_ext` that is filtered to only include specs that are identical to the - current `live_specs`. For collection specs that use schema inference, this will only include - them if the `inferred_schema_md5` matches the `live_inferred_schema_md5`'; - -create function prune_unchanged_draft_specs(prune_draft_id flowid) -returns table( - catalog_name catalog_name, - spec_type catalog_spec_type, - live_spec_md5 text, - draft_spec_md5 text, - inferred_schema_md5 text, - live_inferred_schema_md5 text -) as $$ - with to_prune as ( - select * from unchanged_draft_specs u where u.draft_id = prune_draft_id - ), - del as ( - delete from draft_specs ds - where ds.draft_id = prune_draft_id - and ds.catalog_name in (select catalog_name from to_prune) - ) - select - catalog_name, - spec_type, - live_spec_md5, - draft_spec_md5, - inferred_schema_md5, - live_inferred_schema_md5 - from to_prune -$$ language sql security invoker; - -comment on function prune_unchanged_draft_specs is - 'Deletes draft_specs belonging to the given draft_id that are identical - to the published live_specs. For collection specs that use inferred schemas, - draft_specs will only be deleted if the inferred schema also remains identical.'; - -commit; diff --git a/supabase/migrations/37_cleanup_built_specs.sql b/supabase/migrations/37_cleanup_built_specs.sql deleted file mode 100644 index 239938b0f2..0000000000 --- a/supabase/migrations/37_cleanup_built_specs.sql +++ /dev/null @@ -1,7 +0,0 @@ --- There's been a bug that resulted in the `built_spec` being populated for deleted collections. --- The agent code has been updated to fix the issue, and this just cleans up any affected rows. -begin; - -update live_specs set built_spec = null where spec is null and spec_type is null; - -commit; diff --git a/supabase/migrations/38_change_to_gigabytes.sql b/supabase/migrations/38_change_to_gigabytes.sql deleted file mode 100644 index b32d6c9b15..0000000000 --- a/supabase/migrations/38_change_to_gigabytes.sql +++ /dev/null @@ -1,263 +0,0 @@ -begin; - -alter table tenants alter column data_tiers set default '{50}'; - --- Not used, let's not confuse ourselves with `internal.billing_report_202308` which is used -drop function billing_report; - --- Billing report which is effective August 2023. -create or replace function internal.billing_report_202308(billed_prefix catalog_prefix, billed_month timestamptz) -returns jsonb as $$ -declare - -- Output variables. - o_daily_usage jsonb; - o_data_gb numeric; - o_line_items jsonb = '[]'; - o_recurring_fee integer; - o_subtotal integer; - o_task_hours numeric; - o_trial_credit integer; - o_free_tier_credit integer; - o_trial_start date; - o_trial_range daterange; - o_free_tier_range daterange; - o_billed_range daterange; -begin - - -- Ensure `billed_month` is the truncated start of the billed month. - billed_month = date_trunc('month', billed_month); - - with vars as ( - select - t.data_tiers, - t.trial_start, - t.usage_tiers, - tstzrange(billed_month, billed_month + '1 month', '[)') as billed_range, - case when t.trial_start is not null - then daterange(t.trial_start::date, ((t.trial_start::date) + interval '1 month')::date, '[)') - else 'empty' end as trial_range, - -- In order to smoothly transition between free tier credit and free trial credit, - -- the free tier covers all usage up to, but _not including_ the trial start date. - -- On the trial start date, the free trial credit takes over. - daterange(NULL, t.trial_start::date, '[)') as free_tier_range, - -- Reveal contract costs only when computing whole-tenant billing. - case when t.tenant = billed_prefix then t.recurring_usd_cents else 0 end as recurring_fee - from tenants t - where billed_prefix ^@ t.tenant -- Prefix starts with tenant. - ), - -- Roll up each day's incremental usage. - daily_stat_deltas as ( - select - ts, - sum(bytes_written_by_me + bytes_read_by_me) / (10.0^9.0) as data_gb, - sum(usage_seconds) / (60.0 * 60) as task_hours - from catalog_stats, vars - where catalog_name ^@ billed_prefix -- Name starts with prefix. - and grain = 'daily' - and billed_range @> ts - group by ts - ), - -- Map to cumulative daily usage. - -- Note sum(...) over (order by ts) yields the running sum of its aggregate. - daily_stats as ( - select - ts, - sum(data_gb) over w as data_gb, - sum(task_hours) over w as task_hours - from daily_stat_deltas - window w as (order by ts) - ), - -- Extend with line items for each category for the period ending with the given day. - daily_line_items as ( - select - daily_stats.*, - internal.tier_line_items(ceil(data_gb)::integer, data_tiers, 'Data processing', 'GB') as data_line_items, - internal.tier_line_items(ceil(task_hours)::integer, usage_tiers, 'Task usage', 'hour') as task_line_items - from daily_stats, vars - ), - -- Extend with per-category subtotals for the period ending with the given day. - daily_totals as ( - select - daily_line_items.*, - data_subtotal, - task_subtotal - from daily_line_items, - lateral (select sum((li->>'subtotal')::numeric) as data_subtotal from jsonb_array_elements(data_line_items) li) l1, - lateral (select sum((li->>'subtotal')::numeric) as task_subtotal from jsonb_array_elements(task_line_items) li) l2 - ), - -- Map cumulative totals to per-day deltas. - daily_deltas as ( - select - ts, - data_gb - (coalesce(lag(data_gb, 1) over w, 0)) as data_gb, - data_subtotal - (coalesce(lag(data_subtotal, 1) over w, 0)) as data_subtotal, - task_hours - (coalesce(lag(task_hours, 1) over w, 0)) as task_hours, - task_subtotal - (coalesce(lag(task_subtotal, 1) over w, 0)) as task_subtotal - from daily_totals - window w as (order by ts) - ), - -- 1) Group daily_deltas into a JSON array - -- 2) Sum a trial credit from daily deltas that overlap with the trial period. - daily_array_and_trial_credits as ( - select - jsonb_agg(jsonb_build_object( - 'ts', ts, - 'data_gb', data_gb, - 'data_subtotal', data_subtotal, - 'task_hours', task_hours, - 'task_subtotal', task_subtotal - )) as daily_usage, - coalesce(sum(data_subtotal + task_subtotal) filter (where trial_range @> (ts::date)),0 ) as trial_credit, - coalesce(sum(data_subtotal + task_subtotal) filter (where free_tier_range @> (ts::date)),0 ) as free_tier_credit - from daily_deltas, vars - ), - -- The last day captures the cumulative billed period. - last_day as ( - select * from daily_line_items - order by ts desc limit 1 - ), - -- If we're reporting for the whole tenant then gather billing adjustment line-items. - adjustments as ( - select coalesce(jsonb_agg( - jsonb_build_object( - 'description', detail, - 'count', 1, - 'rate', usd_cents, - 'subtotal', usd_cents - ) - ), '[]') as adjustment_line_items - from internal.billing_adjustments a - where a.tenant = billed_prefix and a.billed_month = billing_report_202308.billed_month - ) - select into - -- Block of variables being selected into. - o_daily_usage, - o_data_gb, - o_line_items, - o_recurring_fee, - o_task_hours, - o_trial_credit, - o_trial_start, - o_trial_range, - o_billed_range, - o_free_tier_credit, - o_free_tier_range - -- The actual selected columns. - daily_usage, - data_gb, - data_line_items || task_line_items || adjustment_line_items, - recurring_fee, - task_hours, - trial_credit, - trial_start, - trial_range, - billed_range, - free_tier_credit, - free_tier_range - from daily_array_and_trial_credits, last_day, adjustments, vars; - - -- Add line items for recurring service fee & free trial credit. - if o_recurring_fee != 0 then - o_line_items = jsonb_build_object( - 'description', 'Recurring service charge', - 'count', 1, - 'rate', o_recurring_fee, - 'subtotal', o_recurring_fee - ) || o_line_items; - end if; - - -- Display a (possibly zero) free trial credit if the trial range overlaps the billed range - if o_trial_range && o_billed_range then - o_line_items = o_line_items || jsonb_build_object( - 'description', format('Free trial credit (%s - %s)', lower(o_trial_range), (upper(o_trial_range) - interval '1 day')::date), - 'count', 1, - 'rate', -o_trial_credit, - 'subtotal', -o_trial_credit - ); - end if; - - -- Display the free tier credit if the free tier range overlaps the billed range - if o_free_tier_range && o_billed_range then - o_line_items = o_line_items || jsonb_build_object( - 'description', case when upper(o_free_tier_range) is not null - then format('Free tier credit ending %s', (upper(o_free_tier_range) - interval '1 day')::date) - else 'Free tier credit' - end, - 'count', 1, - 'rate', -o_free_tier_credit, - 'subtotal', -o_free_tier_credit - ); - end if; - - -- Roll up the final subtotal. - select into o_subtotal sum((l->>'subtotal')::numeric) - from jsonb_array_elements(o_line_items) l; - - return jsonb_build_object( - 'billed_month', billed_month, - 'billed_prefix', billed_prefix, - 'daily_usage', o_daily_usage, - 'line_items', o_line_items, - 'processed_data_gb', o_data_gb, - 'recurring_fee', o_recurring_fee, - 'subtotal', o_subtotal, - 'task_usage_hours', o_task_hours, - 'trial_credit', coalesce(o_trial_credit, 0), - 'free_tier_credit', coalesce(o_free_tier_credit, 0), - 'trial_start', o_trial_start - ); - -end -$$ language plpgsql volatile security definer; - -create or replace view internal.new_free_trial_tenants as -with hours_by_day as ( - select - tenants.tenant as tenant, - ts, - sum(catalog_stats_daily.usage_seconds / (60.0 * 60)) as daily_usage_hours - from catalog_stats_daily - join tenants on catalog_stats_daily.catalog_name ^@ tenants.tenant - where tenants.trial_start is null - group by tenants.tenant, ts - having sum(catalog_stats_daily.usage_seconds / (60.0 * 60)) > (2 * 24) -), -hours_by_month as ( - select - tenants.tenant as tenant, - ts, - sum(catalog_stats_monthly.usage_seconds / (60.0 * 60)) as monthly_usage_hours - from catalog_stats_monthly - join tenants on catalog_stats_monthly.catalog_name ^@ tenants.tenant - where tenants.trial_start is null - group by tenants.tenant, ts - having sum(catalog_stats_monthly.usage_seconds / (60.0 * 60)) > (24 * 31 * 2) -), -gbs_by_month as ( - select - tenants.tenant as tenant, - ts, - ceil(sum((catalog_stats_monthly.bytes_written_by_me + catalog_stats_monthly.bytes_read_by_me) / (10.0^9.0))) as monthly_usage_gbs - from catalog_stats_monthly - join tenants on catalog_stats_monthly.catalog_name ^@ tenants.tenant - where tenants.trial_start is null - group by tenants.tenant, ts - having ceil(sum((catalog_stats_monthly.bytes_written_by_me + catalog_stats_monthly.bytes_read_by_me) / (10.0^9.0))) > 10 -) -select - tenants.tenant as tenant, - max(hours_by_day.daily_usage_hours) as max_daily_usage_hours, - max(hours_by_month.monthly_usage_hours) as max_monthly_usage_hours, - max(gbs_by_month.monthly_usage_gbs) as max_monthly_gb, - count(distinct live_specs.id) filter (where live_specs.spec_type = 'capture') as today_captures, - count(distinct live_specs.id) filter (where live_specs.spec_type = 'materialization') as today_materializations -from tenants -left join hours_by_day on hours_by_day.tenant = tenants.tenant -left join hours_by_month on hours_by_month.tenant = tenants.tenant -left join gbs_by_month on gbs_by_month.tenant = tenants.tenant -join live_specs on (split_part(live_specs.catalog_name,'/',1)||'/' = tenants.tenant and (live_specs.spec #>> '{shards,disable}')::boolean is not true) -where tenants.trial_start is null -group by tenants.tenant -having count(hours_by_month) > 0 or count(hours_by_day) > 0 or count(gbs_by_month) > 0; - -commit; \ No newline at end of file diff --git a/supabase/migrations/39_alerts.sql b/supabase/migrations/39_alerts.sql deleted file mode 100644 index 96a2bb1437..0000000000 --- a/supabase/migrations/39_alerts.sql +++ /dev/null @@ -1,142 +0,0 @@ -begin; - -create table alert_subscriptions ( - like internal._model including all, - - catalog_prefix catalog_prefix not null, - email text -); -alter table alert_subscriptions enable row level security; - -create policy "Users access subscriptions for the prefixes they admin" - on alert_subscriptions as permissive - using (exists( - select 1 from auth_roles('admin') r where catalog_prefix ^@ r.role_prefix - )); - -grant select, insert, update, delete on alert_subscriptions to authenticated; - -create table alert_data_processing ( - catalog_name catalog_name not null, - evaluation_interval interval not null, - primary key (catalog_name) -); -alter table alert_data_processing enable row level security; - -create policy "Users access alerts for admin-authorized tasks" - on alert_data_processing as permissive - using (exists( - select 1 from auth_roles('admin') r where catalog_name ^@ r.role_prefix - )); - -grant update (evaluation_interval) on alert_data_processing to authenticated; -grant select, insert, delete on alert_data_processing to authenticated; - -create table alert_history ( - alert_type text not null, - catalog_name catalog_name not null, - fired_at timestamptz not null, - resolved_at timestamptz, - arguments json not null, - primary key (alert_type, catalog_name, fired_at) -); -alter table alert_history enable row level security; - -create policy "Users access alert history for admin-authorized tasks" - on alert_history as permissive - using (exists( - select 1 from auth_roles('admin') r where catalog_name ^@ r.role_prefix - )); - -grant select on alert_history to authenticated; - -create view internal.alert_data_processing_firing as -select - alert_data_processing.*, - 'data_not_processed_in_interval' as alert_type, - alert_subscriptions.email, - live_specs.spec_type, - coalesce(sum(catalog_stats_hourly.bytes_written_by_me + catalog_stats_hourly.bytes_written_to_me + catalog_stats_hourly.bytes_read_by_me), 0)::bigint as bytes_processed -from alert_data_processing - left join live_specs on alert_data_processing.catalog_name = live_specs.catalog_name and live_specs.spec is not null and (live_specs.spec->'shards'->>'disable')::boolean is not true - left join catalog_stats_hourly on alert_data_processing.catalog_name = catalog_stats_hourly.catalog_name and catalog_stats_hourly.ts >= date_trunc('hour', now() - alert_data_processing.evaluation_interval) - left join alert_subscriptions on alert_data_processing.catalog_name ^@ alert_subscriptions.catalog_prefix and email is not null -where live_specs.created_at <= date_trunc('hour', now() - alert_data_processing.evaluation_interval) -group by - alert_data_processing.catalog_name, - alert_data_processing.evaluation_interval, - alert_subscriptions.email, - live_specs.spec_type -having coalesce(sum(catalog_stats_hourly.bytes_written_by_me + catalog_stats_hourly.bytes_written_to_me + catalog_stats_hourly.bytes_read_by_me), 0)::bigint = 0; - -create view alert_all_firing as -select - internal.alert_data_processing_firing.catalog_name, - internal.alert_data_processing_firing.alert_type, - json_build_object( - 'bytes_processed', internal.alert_data_processing_firing.bytes_processed, - 'emails', array_agg(internal.alert_data_processing_firing.email), - 'evaluation_interval', internal.alert_data_processing_firing.evaluation_interval, - 'spec_type', internal.alert_data_processing_firing.spec_type - ) as arguments -from internal.alert_data_processing_firing -group by - internal.alert_data_processing_firing.catalog_name, - internal.alert_data_processing_firing.alert_type, - internal.alert_data_processing_firing.bytes_processed, - internal.alert_data_processing_firing.evaluation_interval, - internal.alert_data_processing_firing.spec_type -order by catalog_name asc; - -create or replace function internal.evaluate_alert_events() -returns void as $$ -begin - --- Create alerts which have transitioned from !firing => firing -with open_alerts as ( - select alert_type, catalog_name from alert_history - where resolved_at is null -) -insert into alert_history (alert_type, catalog_name, fired_at, arguments) - select alert_type, catalog_name, now(), arguments from alert_all_firing - where (alert_type, catalog_name) not in (select * from open_alerts); - --- Resolve alerts that have transitioned from firing => !firing -with open_alerts as ( - select alert_type, catalog_name from alert_all_firing -) -update alert_history set resolved_at = now() - where resolved_at is null and (alert_type, catalog_name) not in (select * from open_alerts); - -end; -$$ language plpgsql security definer; - -create extension if not exists pg_cron with schema extensions; -select - cron.schedule ( - 'evaluate-alert-events', -- name of the cron job - '*/10 * * * *', -- every ten minutes, update alert event history - $$ select internal.evaluate_alert_events() $$ - ); - -create extension if not exists pg_net with schema extensions; -create or replace function internal.send_alerts() -returns trigger as $trigger$ -begin - -perform - net.http_post( - url:='https://eyrcnmuzzyriypdajwdk.supabase.co/functions/v1/alert-data-processing', - headers:='{"Content-Type": "application/json", "Authorization": "Bearer eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJpc3MiOiJzdXBhYmFzZSIsInJlZiI6ImV5cmNubXV6enlyaXlwZGFqd2RrIiwicm9sZSI6ImFub24iLCJpYXQiOjE2NDg3NTA1NzksImV4cCI6MTk2NDMyNjU3OX0.y1OyXD3-DYMz10eGxzo1eeamVMMUwIIeOoMryTRAoco"}'::jsonb, - body:=concat('{"time": "', now(), '"}')::jsonb - ); - -return null; - -end; -$trigger$ LANGUAGE plpgsql; - -create trigger "Send alerts" after insert or update on alert_history - for each statement execute procedure internal.send_alerts(); - -commit; diff --git a/supabase/migrations/40_resource_path_pointers.sql b/supabase/migrations/40_resource_path_pointers.sql deleted file mode 100644 index 674c755fb8..0000000000 --- a/supabase/migrations/40_resource_path_pointers.sql +++ /dev/null @@ -1,15 +0,0 @@ - -begin; - -create domain json_pointer as text check(value = '' or (value ^@ '/' and length(value) > 1)); - - -alter table connector_tags - add column resource_path_pointers json_pointer[] - check(array_length(resource_path_pointers, 1) > 0); - -comment on column connector_tags.resource_path_pointers is -'The resource_path that was returned from the connector spec response'; - -commit; - diff --git a/supabase/migrations/41_alert_updates.sql b/supabase/migrations/41_alert_updates.sql deleted file mode 100644 index 6b980d261d..0000000000 --- a/supabase/migrations/41_alert_updates.sql +++ /dev/null @@ -1,32 +0,0 @@ -begin; - -create or replace function internal.send_alerts() -returns trigger as $trigger$ -declare - token text; -begin - -select decrypted_secret into token from vault.decrypted_secrets where name = 'alert-email-fn-shared-secret' limit 1; - -if new.alert_type = 'data_not_processed_in_interval' then - perform - net.http_post( - 'https://eyrcnmuzzyriypdajwdk.supabase.co/functions/v1/alert-data-processing', - to_jsonb(new.*), - headers:=format('{"Content-Type": "application/json", "Authorization": "Basic %s"}', token)::jsonb - ); -end if; - -return null; -end; -$trigger$ LANGUAGE plpgsql; - -drop trigger "Send alerts" on alert_history; - -create trigger "Send email after alert fired" after insert on alert_history - for each row execute procedure internal.send_alerts(); - -create trigger "Send email after alert resolved" after update on alert_history - for each row when (old.resolved_at is null and new.resolved_at is not null) execute procedure internal.send_alerts(); - -commit; \ No newline at end of file diff --git a/supabase/migrations/42_stripe_customers.sql b/supabase/migrations/42_stripe_customers.sql deleted file mode 100644 index 154b783e1a..0000000000 --- a/supabase/migrations/42_stripe_customers.sql +++ /dev/null @@ -1,33 +0,0 @@ -begin; - -create schema stripe; -grant usage on schema stripe to postgres; - --- Included here to match the shape of production database so that sqlx can infer queries properly. -create table stripe.customers ( - id text PRIMARY KEY, - address json, - "address/city" text, - "address/country" text, - "address/line1" text, - "address/line2" text, - "address/postal_code" text, - "address/state" text, - balance bigint, - created bigint, - currency text, - default_source text, - delinquent boolean, - description text, - email text, - invoice_prefix text, - invoice_settings json, - "invoice_settings/custom_fields" json, - "invoice_settings/default_payment_method" text, - metadata json, - name text, - phone text, - flow_document json NOT NULL -); - -commit; \ No newline at end of file diff --git a/supabase/migrations/43_payment_emails.sql b/supabase/migrations/43_payment_emails.sql deleted file mode 100644 index 60796fcc0a..0000000000 --- a/supabase/migrations/43_payment_emails.sql +++ /dev/null @@ -1,271 +0,0 @@ -begin; - -create type alert_type as enum ( - 'free_trial', - 'free_trial_ending', - 'free_trial_stalled', - 'missing_payment_method', - 'data_movement_stalled', - 'data_not_processed_in_interval' -- Old alert type -); - -create or replace view internal.alert_free_trial as -select - 'free_trial'::alert_type as alert_type, - (tenants.tenant || 'alerts/free_trial')::catalog_name as catalog_name, - json_build_object( - 'tenant', tenants.tenant, - 'recipients', array_agg(distinct jsonb_build_object( - 'email', alert_subscriptions.email, - 'full_name', auth.users.raw_user_meta_data->>'full_name' - )), - 'trial_start', tenants.trial_start::date, - 'trial_end', (tenants.trial_start + interval '1 month')::date, - -- It's possible for there to be more than one Stripe customer record for a particular tenant - -- in that case, all we care about is that _any_ of them have a payment method set. - 'has_credit_card', bool_or(stripe.customers."invoice_settings/default_payment_method" is not null) - ) as arguments, - -- Since we don't need to communicate post-alert arguments, we can instead - -- simply omit tenants that are no longer in their free trial, and mark the - -- those that are as firing. - ( - tenants.trial_start is not null and - -- Select for tenants currently in their free trials - -- meaning trial start is at most 1 month ago - (now() - tenants.trial_start) < interval '1 month' and - -- Filter out unexpected future start dates - tenants.trial_start <= now() - ) as firing -from tenants - left join alert_subscriptions on alert_subscriptions.catalog_prefix ^@ tenants.tenant and email is not null - left join stripe.customers on stripe.customers."name" = tenants.tenant - -- Filter out sso users because auth.users is only guarinteed unique when that is false: - -- CREATE UNIQUE INDEX users_email_partial_key ON auth.users(email text_ops) WHERE is_sso_user = false; - left join auth.users on auth.users.email = alert_subscriptions.email and auth.users.is_sso_user is false -group by - tenants.tenant, - tenants.trial_start; - --- Trigger 5 days before trial ends -create or replace view internal.alert_free_trial_ending as -select - 'free_trial_ending'::alert_type as alert_type, - (tenants.tenant || 'alerts/free_trial_ending')::catalog_name as catalog_name, - json_build_object( - 'tenant', tenants.tenant, - 'recipients', array_agg(distinct jsonb_build_object( - 'email', alert_subscriptions.email, - 'full_name', auth.users.raw_user_meta_data->>'full_name' - )), - 'trial_start', tenants.trial_start::date, - 'trial_end', (tenants.trial_start + interval '1 month')::date, - 'has_credit_card', bool_or(stripe.customers."invoice_settings/default_payment_method" is not null) - ) as arguments, - ( - tenants.trial_start is not null and - -- e.g "You're >= 25 days into your trial but < 26 days" - (now() - tenants.trial_start) >= (interval '1 month' - interval '5 days') and - (now() - tenants.trial_start) < (interval '1 month' - interval '4 days') and - -- Filter out unexpected future start dates - tenants.trial_start <= now() - ) as firing -from tenants - left join alert_subscriptions on alert_subscriptions.catalog_prefix ^@ tenants.tenant and email is not null - left join stripe.customers on stripe.customers."name" = tenants.tenant - -- Filter out sso users because auth.users is only guarinteed unique when that is false: - -- CREATE UNIQUE INDEX users_email_partial_key ON auth.users(email text_ops) WHERE is_sso_user = false; - left join auth.users on auth.users.email = alert_subscriptions.email and auth.users.is_sso_user is false -group by - tenants.tenant, - tenants.trial_start; - --- Alert us internally when they go past 5 days over the trial -create or replace view internal.alert_free_trial_stalled as -select - 'free_trial_stalled'::alert_type as alert_type, - (tenants.tenant || 'alerts/free_trial_stalled')::catalog_name as catalog_name, - json_build_object( - 'tenant', tenants.tenant, - 'recipients', array_agg(distinct jsonb_build_object( - 'email', alert_subscriptions.email, - 'full_name', auth.users.raw_user_meta_data->>'full_name' - )), - 'trial_start', tenants.trial_start::date, - 'trial_end', (tenants.trial_start + interval '1 month')::date - ) as arguments, - true as firing -from tenants - left join alert_subscriptions on alert_subscriptions.catalog_prefix ^@ tenants.tenant and email is not null - left join stripe.customers on stripe.customers."name" = tenants.tenant - -- Filter out sso users because auth.users is only guarinteed unique when that is false: - -- CREATE UNIQUE INDEX users_email_partial_key ON auth.users(email text_ops) WHERE is_sso_user = false; - left join auth.users on auth.users.email = alert_subscriptions.email and auth.users.is_sso_user is false -where tenants.trial_start is not null and - -- e.g You're 5 days past the end of your trial and you haven't entered a credit card - (now() - tenants.trial_start) >= (interval '1 month' + interval '5 days') and - -- Filter out unexpected future start dates - tenants.trial_start <= now() and - stripe.customers."invoice_settings/default_payment_method" is null -group by - tenants.tenant, - tenants.trial_start; - --- We created this alert so we can notify when it _stops_ firing, i.e --- when a tenant provides a payment method. -create or replace view internal.alert_missing_payment_method as -select - 'missing_payment_method'::alert_type as alert_type, - (tenants.tenant || 'alerts/missing_payment_method')::catalog_name as catalog_name, - json_build_object( - 'tenant', tenants.tenant, - 'recipients', array_agg(distinct jsonb_build_object( - 'email', alert_subscriptions.email, - 'full_name', auth.users.raw_user_meta_data->>'full_name' - )), - 'trial_start', tenants.trial_start::date, - 'trial_end', (tenants.trial_start + interval '1 month')::date, - -- if tenants.trial_start is null, that means they entered their cc - -- while they're still in the free tier - 'plan_state', ( - case - when tenants.trial_start is null then 'free_tier' - when (now() - tenants.trial_start) < interval '1 month' then 'free_trial' - else 'paid' - end - ) - ) as arguments, - bool_or(stripe.customers."invoice_settings/default_payment_method" is null) as firing -from tenants - left join alert_subscriptions on alert_subscriptions.catalog_prefix ^@ tenants.tenant and email is not null - left join stripe.customers on stripe.customers."name" = tenants.tenant - -- Filter out sso users because auth.users is only guarinteed unique when that is false: - -- CREATE UNIQUE INDEX users_email_partial_key ON auth.users(email text_ops) WHERE is_sso_user = false; - left join auth.users on auth.users.email = alert_subscriptions.email and auth.users.is_sso_user is false -group by - tenants.tenant, - tenants.trial_start; - --- Have to update this to join in auth.users for full_name support -create or replace view internal.alert_data_movement_stalled as -select - 'data_movement_stalled'::alert_type as alert_type, - alert_data_processing.catalog_name as catalog_name, - json_build_object( - 'bytes_processed', coalesce(sum(catalog_stats_hourly.bytes_written_by_me + catalog_stats_hourly.bytes_written_to_me + catalog_stats_hourly.bytes_read_by_me), 0)::bigint, - 'recipients', array_agg(distinct jsonb_build_object( - 'email', alert_subscriptions.email, - 'full_name', auth.users.raw_user_meta_data->>'full_name' - )), - 'evaluation_interval', alert_data_processing.evaluation_interval, - 'spec_type', live_specs.spec_type - ) as arguments, - true as firing -from alert_data_processing - left join live_specs on alert_data_processing.catalog_name = live_specs.catalog_name and live_specs.spec is not null and (live_specs.spec->'shards'->>'disable')::boolean is not true - left join catalog_stats_hourly on alert_data_processing.catalog_name = catalog_stats_hourly.catalog_name and catalog_stats_hourly.ts >= date_trunc('hour', now() - alert_data_processing.evaluation_interval) - left join alert_subscriptions on alert_data_processing.catalog_name ^@ alert_subscriptions.catalog_prefix and email is not null - -- Filter out sso users because auth.users is only guarinteed unique when that is false: - -- CREATE UNIQUE INDEX users_email_partial_key ON auth.users(email text_ops) WHERE is_sso_user = false; - left join auth.users on auth.users.email = alert_subscriptions.email and auth.users.is_sso_user is false -where live_specs.created_at <= date_trunc('hour', now() - alert_data_processing.evaluation_interval) -group by - alert_data_processing.catalog_name, - alert_data_processing.evaluation_interval, - live_specs.spec_type -having coalesce(sum(catalog_stats_hourly.bytes_written_by_me + catalog_stats_hourly.bytes_written_to_me + catalog_stats_hourly.bytes_read_by_me), 0)::bigint = 0; - -create or replace view alert_all as - select * from internal.alert_free_trial - union all select * from internal.alert_free_trial_ending - union all select * from internal.alert_free_trial_stalled - union all select * from internal.alert_missing_payment_method - union all select * from internal.alert_data_movement_stalled; - --- Keep track of the alert arguments at the time it was resolved -alter table alert_history - add column resolved_arguments jsonb, - alter column alert_type type alert_type using alert_type::alert_type; - - --- In order to allow alerts to contain arguments after they're done firing --- we need to refactor alerts to contain a `firing` boolean, rather than --- simply omitting no-longer-firing alerts from the view. -create or replace function internal.evaluate_alert_events() -returns void as $$ -begin - - -- Create alerts which have transitioned from !firing => firing - with open_alerts as ( - select alert_type, catalog_name from alert_history - where resolved_at is null - ) - insert into alert_history (alert_type, catalog_name, fired_at, arguments) - select alert_all.alert_type, alert_all.catalog_name, now(), alert_all.arguments - from alert_all - left join open_alerts on - alert_all.alert_type = open_alerts.alert_type and - alert_all.catalog_name = open_alerts.catalog_name - where alert_all.firing and open_alerts is null; - - -- Resolve alerts that have transitioned from firing => !firing - with open_alerts as ( - select - alert_history.alert_type, - alert_history.catalog_name, - fired_at - from alert_history - where resolved_at is null - ), - -- Find all open_alerts for which either there is not a row in alerts_all, - -- or there is but its firing field is false. - closing_alerts as ( - select - open_alerts.alert_type, - open_alerts.catalog_name, - fired_at, - coalesce(alert_all.arguments, null) as arguments - from open_alerts - left join alert_all on - alert_all.alert_type = open_alerts.alert_type and - alert_all.catalog_name = open_alerts.catalog_name - where - -- The open alert is no longer in alert_all, therefore it's no longer firing - alert_all.alert_type is null or - -- The open is still tracked, but it has stopped firing - not alert_all.firing - ) - update alert_history - set resolved_at = now(), - resolved_arguments = closing_alerts.arguments - from closing_alerts - where alert_history.alert_type = closing_alerts.alert_type - and alert_history.catalog_name = closing_alerts.catalog_name - and alert_history.fired_at = closing_alerts.fired_at; - -end; -$$ language plpgsql security definer; - -create or replace function internal.send_alerts() -returns trigger as $trigger$ -declare - token text; -begin - select decrypted_secret into token from vault.decrypted_secrets where name = 'alert-email-fn-shared-secret' limit 1; - perform - net.http_post( - -- 'http://host.docker.internal:5431/functions/v1/alerts', - 'https://eyrcnmuzzyriypdajwdk.supabase.co/functions/v1/alerts', - to_jsonb(new.*), - headers:=format('{"Content-Type": "application/json", "Authorization": "Basic %s"}', token)::jsonb - ); - return null; -end; -$trigger$ LANGUAGE plpgsql; - -create or replace trigger "Send email after alert fired" after insert on alert_history - for each row execute procedure internal.send_alerts(); - -create or replace trigger "Send email after alert resolved" after update on alert_history - for each row when (old.resolved_at is null and new.resolved_at is not null) execute procedure internal.send_alerts(); - -commit; \ No newline at end of file diff --git a/supabase/migrations/44_draft_associated_collections.sql b/supabase/migrations/44_draft_associated_collections.sql deleted file mode 100644 index d0bcea3f04..0000000000 --- a/supabase/migrations/44_draft_associated_collections.sql +++ /dev/null @@ -1,66 +0,0 @@ -begin; - --- Update permissions for live_spec_flows to allow users to directly access it as long as they --- have access to at least one side. This may allow users to know the id of specifications that --- they are not authorized to, but nothing else. -alter policy "Users must be authorized to referenced specifications" on live_spec_flows - rename to "Users must be authorized to one referenced specification"; - --- This policy is tecnically a little more permissive than we truly want, though that seems --- acceptable since it only allows clients to get the ids of connected specs, not anything else. --- If you have read-only access to a spec, then you can see the ids of all connected specs. --- Ideally, you'd only be able to select rows for which you have admin capability to at least --- one side, _or_ at least read capability to _both_ sides. Such a policy seems computationally --- expensive and complicated to write, though, so this is a compromise. -alter policy "Users must be authorized to one referenced specification" on live_spec_flows - using ( - source_id in (select id from live_specs) or - target_id in (select id from live_specs) - ); -grant select on live_spec_flows to authenticated; - -create or replace function draft_collections_eligible_for_deletion(capture_id flowid, draft_id flowid) -returns void as $$ -begin - - insert into draft_specs (draft_id, catalog_name, expect_pub_id, spec, spec_type) - with target_collections as ( - select target_id from live_spec_flows - where source_id = capture_id - ), - collections_read as ( - select target_collections.target_id from target_collections - join live_spec_flows lsf on target_collections.target_id = lsf.source_id - ), - collections_written as ( - select target_collections.target_id from target_collections - join live_spec_flows lsf on target_collections.target_id = lsf.target_id and lsf.source_id <> capture_id - ), - ineligible_collections as ( - select target_id from collections_read - union select target_id from collections_written - ), - eligible_collection_ids as ( - select target_id from target_collections - except select target_id from ineligible_collections - ), - eligible_collections as ( - select - ls.id, - ls.catalog_name, - ls.last_pub_id - from eligible_collection_ids - join live_specs ls on eligible_collection_ids.target_id = ls.id - ) - select draft_id, catalog_name, last_pub_id, null, null from eligible_collections; - -end; -$$ language plpgsql security invoker; - -comment on function draft_collections_eligible_for_deletion is ' -draft_collections_eligible_for_deletion facilitates the deletion of a capture and its associated collections -in the same publication by populating the specified draft with the collections eligible for deletion. -The specified draft should contain the capture pending deletion. -'; - -commit; diff --git a/supabase/migrations/45_background_jobs.sql b/supabase/migrations/45_background_jobs.sql deleted file mode 100644 index 76ea3713a6..0000000000 --- a/supabase/migrations/45_background_jobs.sql +++ /dev/null @@ -1,101 +0,0 @@ --- Introduces the ability to distinguish between background and interactive jobs. Interactive jobs --- are those that users may be actively awaiting. They are identified by having `background = false`, --- which is the default. The agent will process all jobs where `background = false` before it processes --- any that have `background = true`. Background jobs are expected to be things like auto-discovers, --- and the ultimate goal is to prevent things like auto-discovers causing delays in jobs that users --- are actively waiting on. -begin; - -alter table internal._model_async add column background boolean not null default false; -comment on column internal._model_async.background is - 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; - -alter table discovers add column background boolean not null default false; -comment on column discovers.background is - 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; - -alter table publications add column background boolean not null default false; -comment on column publications.background is - 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; - -alter table connector_tags add column background boolean not null default false; -comment on column connector_tags.background is - 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; - -alter table applied_directives add column background boolean not null default false; -comment on column applied_directives.background is - 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; - -alter table evolutions add column background boolean not null default false; -comment on column evolutions.background is - 'indicates whether this is a background job, which will be processed with a lower priority than interactive jobs'; - --- Previously defined in 20_auto_discovers.sql, and re-created here to set `background = true`. -create or replace function internal.create_auto_discovers() -returns integer as $$ -declare - support_user_id uuid = (select id from auth.users where email = 'support@estuary.dev'); - next_row internal.next_auto_discovers; - total_created integer := 0; - tmp_draft_id flowid; - tmp_discover_id flowid; -begin - -for next_row in select * from internal.next_auto_discovers -loop - -- Create a draft, which we'll discover into - insert into drafts (user_id) values (support_user_id) returning id into tmp_draft_id; - - insert into discovers (capture_name, draft_id, connector_tag_id, endpoint_config, update_only, auto_publish, auto_evolve, background) - values ( - next_row.capture_name, - tmp_draft_id, - next_row.connector_tags_id, - next_row.endpoint_json, - not next_row.add_new_bindings, - true, - next_row.evolve_incompatible_collections, - true - ) returning id into tmp_discover_id; - - -- This is just useful when invoking the function manually. - total_created := total_created + 1; -end loop; - -return total_created; -end; -$$ language plpgsql security definer; - -comment on function internal.create_auto_discovers is -'Creates discovers jobs for each capture that is due for an automatic discover. Each disocver will have auto_publish -set to true. The update_only and auto_evolve columns of the discover will be set based on the addNewBindings and -evolveIncompatibleCollections fields in the capture spec. This function is idempotent. Once a discover is created by -this function, the next_auto_discovers view will no longer include that capture until its interval has passed again. -So its safe to call this function at basically any frequency. The return value of the function is the count of newly -created discovers jobs.'; - --- Re-define these triggers to execute for each row, but only for queued jobs. --- This cuts down on extraneous queries resulting from the agents own `update` statements. --- This is also an opportunity to use more consistent naming. -drop trigger "Notify agent about changes to publication" on publications; -drop trigger "Notify agent about changes to discover requests" on discovers; -drop trigger "Notify agent of applied directive" on applied_directives; -drop trigger "Notify agent about changes to connector_tags" on connector_tags; -drop trigger "Notify agent about changes to evolution" on evolutions; - -create trigger publications_agent_notifications after insert or update on publications -for each row when (NEW.job_status->>'type' = 'queued') execute procedure internal.notify_agent(); - -create or replace trigger discovers_agent_notifications after insert or update on discovers -for each row when (NEW.job_status->>'type' = 'queued') execute procedure internal.notify_agent(); - -create or replace trigger applied_directives_agent_notifications after insert or update on applied_directives -for each row when (NEW.job_status->>'type' = 'queued') execute procedure internal.notify_agent(); - -create or replace trigger connector_tags_agent_notifications after insert or update on connector_tags -for each row when (NEW.job_status->>'type' = 'queued') execute procedure internal.notify_agent(); - -create or replace trigger evolutions_agent_notifications after insert or update on evolutions -for each row when (NEW.job_status->>'type' = 'queued') execute procedure internal.notify_agent(); - -commit; diff --git a/supabase/migrations/46_google_cloud_marketplace.sql b/supabase/migrations/46_google_cloud_marketplace.sql deleted file mode 100644 index 284ef4e70c..0000000000 --- a/supabase/migrations/46_google_cloud_marketplace.sql +++ /dev/null @@ -1,25 +0,0 @@ -begin; - -create table internal.gcm_accounts( - id uuid not null primary key, - obfuscated_id text, - entitlement_id uuid, - - approved boolean default false -); - -comment on column internal.gcm_accounts.id is - 'Google marketplace user ID, received in the first ACCOUNT_ACTIVE pub/sub event and as the subject of the JWT token during signup'; - -comment on column internal.gcm_accounts.obfuscated_id is - 'Google GAIA ID, received in JWT during sign-up, can be used to sign the user in using OAuth2'; - -comment on column internal.gcm_accounts.approved is - 'Has the account been approved with Google'; - -create unique index idx_gcm_accounts_id_where_approved on internal.gcm_accounts(id) - where approved=true; - -alter table tenants add column if not exists gcm_account_id uuid references internal.gcm_accounts(id); - -commit; diff --git a/supabase/migrations/47_registered_avro_schemas.sql b/supabase/migrations/47_registered_avro_schemas.sql deleted file mode 100644 index 525a04e141..0000000000 --- a/supabase/migrations/47_registered_avro_schemas.sql +++ /dev/null @@ -1,32 +0,0 @@ - -create table registered_avro_schemas ( - like internal._model including all, - - avro_schema json not null, - avro_schema_md5 text generated always as (md5(trim(avro_schema::text))) stored, - catalog_name catalog_name not null, - registry_id serial unique not null -); - -create index idx_registered_avro_schemas_avro_schema_md5 on registered_avro_schemas (avro_schema_md5); - -comment on table registered_avro_schemas is ' -Avro schemas registered with a globally unique, stable registery ID. - -This is used to emulate the behavior of Confluent Schema Registry when -transcoding collection documents into Avro for use with Dekaf, -which must encode each message with an Avro schema ID (registry_id). -'; - -alter table registered_avro_schemas enable row level security; - -create policy "Users must be read-authorized to the schema catalog name" - on registered_avro_schemas as permissive - using (exists( - select 1 from auth_roles('read') r where catalog_name ^@ r.role_prefix - )); - -grant select on registered_avro_schemas to authenticated; -grant insert (catalog_name, avro_schema) on registered_avro_schemas to authenticated; -grant update (updated_at) on registered_avro_schemas to authenticated; -grant usage on sequence registered_avro_schemas_registry_id_seq to authenticated; \ No newline at end of file diff --git a/supabase/migrations/48_storage_mapping_directive.sql b/supabase/migrations/48_storage_mapping_directive.sql deleted file mode 100644 index 721f5e1915..0000000000 --- a/supabase/migrations/48_storage_mapping_directive.sql +++ /dev/null @@ -1,31 +0,0 @@ - -begin; - --- Add the storageMappings directive, using a static token so that we can hard code the token in the UI. --- This token is not sensitive, and is safe to be shared publicly. -insert into directives (catalog_prefix, spec, token) values ('ops/', '{"type": "storageMappings"}', 'dd1319b2-e72b-421c-ad2b-082352569bb1'); - -create or replace function republish_prefix(prefix catalog_prefix) -returns flowid as $$ -declare - draft_id flowid; - pub_id flowid; -begin - insert into drafts default values returning id into draft_id; - insert into draft_specs (draft_id, catalog_name, spec_type, spec, expect_pub_id) - select draft_id, catalog_name, spec_type, spec, last_pub_id as expect_pub_id - from live_specs - where starts_with(catalog_name, prefix) and spec_type is not null; - - insert into publications (draft_id) values (draft_id) returning id into pub_id; - return pub_id; -end; -$$ language plpgsql security invoker; - -comment on function republish_prefix is -'Creates a publication of every task and collection under the given prefix. This will not modify any -of the specs, and will set expect_pub_id to ensure that the publication does not overwrite changes -from other publications. This is intended to be called after an update to the storage mappings of -the prefix to apply the updated mappings.'; - -commit; diff --git a/supabase/migrations/49_tenant_hide_preview.sql b/supabase/migrations/49_tenant_hide_preview.sql deleted file mode 100644 index d983572666..0000000000 --- a/supabase/migrations/49_tenant_hide_preview.sql +++ /dev/null @@ -1,9 +0,0 @@ -begin; - -alter table tenants add column hide_preview boolean not null default false; - -comment on column tenants.hide_preview is ' -Hide data preview in the collections page for this tenant, used as a measure for preventing users with access to this tenant from viewing sensitive data in collections -'; - -commit; diff --git a/supabase/migrations/50_controllers.sql b/supabase/migrations/50_controllers.sql deleted file mode 100644 index f6a3eec6dc..0000000000 --- a/supabase/migrations/50_controllers.sql +++ /dev/null @@ -1,125 +0,0 @@ -begin; - - -create type flow_type as enum ( - -- These correspond 1:1 with catalog_spec_type. - 'capture', - 'collection', - 'materialization', - 'test', - -- These do not - 'source_capture' -); -comment on type flow_type is - 'Represents the type of a dependency of one spec on another. This enum is a - strict superset of catalog_spec_type, for historical reasons.'; - --- This cast, specifically the `as assignment`, is required to allow the old version --- of control plane to continue to insert `catalog_spec_type`s into the `flow_type` --- column. -create cast (catalog_spec_type as flow_type) with inout as assignment; - --- This works because the `flow_type` enum is a superset of the `catalog_spec_type` enum. --- This approach was taken from: --- https://www.munderwood.ca/index.php/2015/05/28/altering-postgresql-columns-from-one-enum-to-another/ -alter table live_spec_flows -alter column flow_type set data type flow_type -using flow_type::flow_type; - --- Update live_spec_flows foreign keys to add `on delete cascade` -alter table live_spec_flows -drop constraint live_spec_flows_source_id_fkey; -alter table live_spec_flows -drop constraint live_spec_flows_target_id_fkey; - -alter table live_spec_flows -add constraint live_spec_flows_source_id_fkey -foreign key(source_id) references live_specs(id) on delete cascade; -alter table live_spec_flows -add constraint live_spec_flows_target_id_fkey -foreign key(target_id) references live_specs(id) on delete cascade; - -alter table live_specs add column controller_next_run timestamptz; -comment on column live_specs.controller_next_run is 'The next time the controller for this spec should run.'; - --- Create a partial covering index on live specs to facilitate querying for the next controller run. --- This is used by `deque` in `agent-sql/src/controllers.rs`. -create index live_specs_controller_next_run on live_specs(controller_next_run) -include (id) -where controller_next_run is not null; - --- This constraint is removed because we're changing how we represent deleted specs, so that only --- the `spec` column is null. Setting `spec_type` to null was unnecessary, and retaining it is --- now necessary in order for `live_spec_flows` to stay consistent with `live_specs` in case of --- spec deletions that don't draft all the connected specs. Note that spec_type columns are still --- nullable to maintain compatibility with old agent versions during the transition. -alter table live_specs drop constraint "spec and spec_type must be consistent"; -alter table draft_specs drop constraint "spec and spec_type must be consistent"; --- Allow spec_type to remain non-null for deleted specs -alter table publication_specs drop constraint "spec and spec_type must be consistent"; - - -create table controller_jobs ( - -- The name of the live spec that this pertains to - live_spec_id flowid not null references live_specs (id) on delete cascade, - -- The version of the controller that last updated this row. Used to identify controllers to run - -- whenever we update the controller code. Is compared to the `agent::controllers::CONTROLLER_VERSION` - -- constant. - controller_version integer not null default 0, - - -- Arbitrary JSON that's updated by the controller. Can be used as state for the controller, - -- and also for communicating status to end users. - status json not null default '{}'::json, - -- Informational only - updated_at timestamptz not null default now(), - - -- Always use the same logs_token for each controller, so the logs from all runs are in one place - logs_token uuid not null default gen_random_uuid(), - - -- Error handling still needs more consideration - failures integer not null default 0, - -- Errors executing the controller will be shown here - error text, - - primary key (live_spec_id) -); - -comment on table controller_jobs is - 'Controller jobs reflect the state of the automated background processes that - manage live specs. Controllers are responsible for things like updating - inferred schemas, activating and deleting shard and journal specs in the data - plane, and any other type of background automation.'; - -comment on column controller_jobs.live_spec_id is - 'The id of the live_specs row that this contoller job pertains to.'; -comment on column controller_jobs.controller_version is - 'The version of the controller that last ran. This number only increases - monotonically, and only when a breaking change to the controller status - is released. Every controller_job starts out with a controller_version of 0, - and will subsequently be upgraded to the current controller version by the - first controller run.'; -comment on column controller_jobs.status is - 'Contains type-specific information about the controller and the actions it - has performed.'; -comment on column controller_jobs.updated_at is - 'Timestamp of the last update to the controller_job.'; -comment on column controller_jobs.logs_token is - 'Token that can be used to query logs from controller runs from - internal.log_lines.'; -comment on column controller_jobs.failures is - 'Count of consecutive failures of this controller. This is reset to 0 upon - any successful controller run. If failures is > 0, then error will be set'; -comment on column controller_jobs.error is - 'The error from the most recent controller run, which will be null if the - run was successful. If this is set, then failures will be > 0'; - -alter table controller_jobs enable row level security; - -create policy "Users must be authorized to live specifications" - on controller_jobs as permissive for select - using ( - live_spec_id in (select id from live_specs) - ); -grant select on live_specs to authenticated; - -commit; diff --git a/supabase/migrations/51_backfill_controllers.sql b/supabase/migrations/51_backfill_controllers.sql deleted file mode 100644 index 919c16e199..0000000000 --- a/supabase/migrations/51_backfill_controllers.sql +++ /dev/null @@ -1,25 +0,0 @@ --- Backfills a chunk of controller_jobs rows, kicking off controllers for that chunk of live specs. --- This allows us to incrementally enable controllers for tasks that were last published by --- prior versions of the agent. The idea is to run this migration repeatedly until it stops returning --- any rows. -begin; - -with insert_controller_jobs(live_spec_id) as ( - insert into controller_jobs (live_spec_id) - select id from live_specs - where id not in (select live_spec_id from controller_jobs) - and ( - (built_spec is not null and spec is not null) - or (built_spec is null and spec is null) - ) - limit 100 - -- on conflict can't hurt anything and I just can't be bothered to go through - -- the read-committed docs right now to prove to myself that it isn't necessary. - on conflict(live_spec_id) do nothing - returning live_spec_id -) -update live_specs set controller_next_run = now() -where id in (select live_spec_id from insert_controller_jobs) -returning id, catalog_name; - -commit; diff --git a/supabase/migrations/52_extend_pg_net_timeout.sql b/supabase/migrations/52_extend_pg_net_timeout.sql deleted file mode 100644 index 70bb299023..0000000000 --- a/supabase/migrations/52_extend_pg_net_timeout.sql +++ /dev/null @@ -1,21 +0,0 @@ -begin; - -create or replace function internal.send_alerts() -returns trigger as $trigger$ -declare - token text; -begin - select decrypted_secret into token from vault.decrypted_secrets where name = 'alert-email-fn-shared-secret' limit 1; - perform - net.http_post( - -- 'http://host.docker.internal:5431/functions/v1/alerts', - 'https://eyrcnmuzzyriypdajwdk.supabase.co/functions/v1/alerts', - to_jsonb(new.*), - headers:=format('{"Content-Type": "application/json", "Authorization": "Basic %s"}', token)::jsonb, - timeout_milliseconds:=90000 - ); - return null; -end; -$trigger$ LANGUAGE plpgsql; - -commit; \ No newline at end of file diff --git a/supabase/migrations/53_rls_perf.sql b/supabase/migrations/53_rls_perf.sql deleted file mode 100644 index cbd72ddce7..0000000000 --- a/supabase/migrations/53_rls_perf.sql +++ /dev/null @@ -1,274 +0,0 @@ -begin; - --- Updates RLS policies to use `(select auth.uid())` as recommended by: --- https://supabase.com/docs/guides/database/postgres/row-level-security#call-functions-with-select -alter policy "Users can access only their created drafts" - on drafts - using (user_id = (select auth.uid())); - - -alter policy "Users select user grants they admin or are the subject" - on user_grants - using (exists( - select 1 from auth_roles('admin') r where object_role ^@ r.role_prefix - ) or user_id = (select auth.uid())); - -alter policy "Users delete user grants they admin or are the subject" - on user_grants - using (exists( - select 1 from auth_roles('admin') r where object_role ^@ r.role_prefix - ) or user_id = (select auth.uid())); - -alter policy "Users can access only their initiated publish operations" - on publications - using (user_id = (select auth.uid())); - -alter policy "Users can access only their initiated evolution operations" - on evolutions - using (user_id = (select auth.uid())); - -alter policy "Users can access only their applied directives" - on applied_directives - using (user_id = (select auth.uid())); - -alter policy "Users can access their own refresh tokens" - on refresh_tokens - using (user_id = (select auth.uid())); - --- Althought the `user_id` condition here is not necessary for correctness, --- making it explicit in the query helps the query planner -alter policy "Users can access and delete errors of their drafts" - on draft_errors - using (draft_id in (select id from drafts where user_id = (select auth.uid()) )); - -alter policy "Users access their draft specs" - on draft_specs - using (draft_id in (select id from drafts where user_id = (select auth.uid()) )); - --- Changing the return type of the id_generator function was recommended by supabase support, --- as a way of mitigating issues with pg-dump|restore due to recursion in the schema. -alter domain flowid drop default; -drop function internal.id_generator(); - -create function internal.id_generator() - returns macaddr8 as $$ - declare - -- This procedure generates unique 64-bit integers - -- with the following bit layout: - -- - -- 0b00000010100000101011010111111000100000101010100100011111100011100 - -- |-- Timestamp Millis --||-- SeqNo --||- Shard-| - -- - -- Estuary epoch is the first representable timestamp in generated IDs. - -- This could be zero, but subtracting |estuary_epoch| results in the - -- high bit being zero for the next ~34 years, - -- making ID representations equivalent for both signed and - -- unsigned 64-bit integers. - estuary_epoch bigint := 1600000000; - -- The id of this parallizable ID generation shard. - -- ID's generated inside of PostgreSQL always use |shard_id| zero. - -- We reserve other shard IDs for future parallized ID generation. - -- The allowed range is [0, 1024) (10 bits). - shard_id int := 0; - -- Sequence number is a monotonic tie-breaker for IDs generated - -- within the same millisecond. - -- The allowed range is [0, 8192) (13 bits). - seq_no bigint; - -- Current timestamp, as Unix millis since |estuary_epoch|. - now_millis bigint; - begin - -- We have 13 low bits of sequence ID, which allow us to generate - -- up to 8,192 unique IDs within each given millisecond. - select nextval('internal.shard_0_id_sequence') % 8192 into seq_no; - - select floor((extract(epoch from clock_timestamp()) - estuary_epoch) * 1000) into now_millis; - return lpad(to_hex((now_millis << 23) | (seq_no << 10) | (shard_id)), 16, '0')::macaddr8; - end; - $$ language plpgsql - security definer; - - comment on function internal.id_generator is ' - id_generator produces 64bit unique, non-sequential identifiers. They: - * Have fixed storage that''s 1/2 the size of a UUID. - * Have a monotonic generation order. - * Embed a wall-clock timestamp than can be extracted if needed. - * Avoid the leaky-ness of SERIAL id''s. - - Adapted from: https://rob.conery.io/2014/05/29/a-better-id-generator-for-postgresql/ - Which itself was inspired by http://instagram-engineering.tumblr.com/post/10853187575/sharding-ids-at-instagram - '; - - alter domain flowid set default internal.id_generator(); - --- Create indexes to help with dequeuing pending publications, discovers, and evolutions -create index publications_queued on publications(id) where job_status->>'type' = 'queued'; -create index discovers_queued on discovers(id) where job_status->>'type' = 'queued'; -create index evolutions_queued on evolutions(id) where job_status->>'type' = 'queued'; - - --- update combined_grants_ext to use `(select auth.uid())` just like in the RLS policies -create or replace view combined_grants_ext as - with admin_roles as ( - -- Extract into CTE so it's evaluated once, not twice. - -- This is only required because of the union, which produces - -- entirely separate evaluation nodes within the query plan - -- that naievely don't share the auth_roles() result. - select role_prefix from auth_roles('admin') - ), - user_id(id) as ( - -- Also to ensure that it's evaluated once instead of for each row - select auth.uid() - ) - select - g.capability, - g.created_at, - g.detail, - g.id, - g.object_role, - g.updated_at, - -- - g.subject_role, - -- - null as user_avatar_url, - null as user_email, - null as user_full_name, - null as user_id - from role_grants g - where g.id in ( - -- User must admin subject or object role. Compare to select RLS policy. - select g.id from admin_roles r, role_grants g - where g.subject_role ^@ r.role_prefix or g.object_role ^@ r.role_prefix - ) - union all - select - g.capability, - g.created_at, - g.detail, - g.id, - g.object_role, - g.updated_at, - -- - null as subject_role, - -- - u.avatar_url as user_avatar_url, - u.email as user_email, - u.full_name as user_full_name, - g.user_id as user_id - from user_grants g - left outer join internal.user_profiles u on u.user_id = g.user_id - where g.id in ( - -- User must admin object role or be the user. Compare to select RLS policy. - select g.id from admin_roles r, user_grants g - where g.user_id = (select id from user_id) or g.object_role ^@ r.role_prefix - ) - ; - -- combined_grants_ext includes its own authorization checks. - grant select on combined_grants_ext to authenticated; - -comment on view combined_grants_ext is - 'Combined view of `role_grants` and `user_grants` extended with user metadata'; - - --- Re-define the live_specs_ext view to hoist the `auth_roles` call into a CTE so that it gets --- evaluated only once. Drop and re-create the views because `select *` resolves to different --- columns. This means that we also need to drop and re-create all dependent views :/ -drop view unchanged_draft_specs; -drop view draft_specs_ext; -drop view live_specs_ext; - --- l.* expands to an additional column now, but columns are otherwise identical to the previous view definition --- Extended view of live catalog specifications. -create view live_specs_ext as -with authorized_specs as ( - -- User must be able to read catalog_name. Compare to select RLS policy. - select l.id from auth_roles('read') r, live_specs l - where l.catalog_name ^@ r.role_prefix -) -select - l.*, - c.external_url as connector_external_url, - c.id as connector_id, - c.title as connector_title, - c.short_description as connector_short_description, - c.logo_url as connector_logo_url, - c.recommended as connector_recommended, - t.id as connector_tag_id, - t.documentation_url as connector_tag_documentation_url, - p.detail as last_pub_detail, - p.user_id as last_pub_user_id, - u.avatar_url as last_pub_user_avatar_url, - u.email as last_pub_user_email, - u.full_name as last_pub_user_full_name -from live_specs l -left outer join publication_specs p on l.id = p.live_spec_id and l.last_pub_id = p.pub_id -left outer join connectors c on c.image_name = l.connector_image_name -left outer join connector_tags t on c.id = t.connector_id and l.connector_image_tag = t.image_tag -left outer join internal.user_profiles u on u.user_id = p.user_id --- This first condition allows superusers to query the view. The second is the normal RLS policy, --- but implemented here in a way that is more efficient when querying for large sets of specs. -where exists(select 1 from pg_roles where rolname = current_role and rolbypassrls = true) - or l.id in (select id from authorized_specs) -; --- live_specs_ext includes its own authorization checks. -grant select on live_specs_ext to authenticated; - -comment on view live_specs_ext is - 'View of `live_specs` extended with metadata of its last publication'; - --- Extended view of user draft specifications. -create view draft_specs_ext as -with authorized_drafts as ( - select id from drafts where user_id = (select auth.uid()) -) -select - d.*, - l.last_pub_detail, - l.last_pub_id, - l.last_pub_user_id, - l.last_pub_user_avatar_url, - l.last_pub_user_email, - l.last_pub_user_full_name, - l.spec as live_spec, - l.spec_type as live_spec_type, - -- new columns below - s.md5 as inferred_schema_md5, - l.inferred_schema_md5 as live_inferred_schema_md5, - l.md5 as live_spec_md5, - md5(trim(d.spec::text)) as draft_spec_md5 -from draft_specs d -left outer join live_specs_ext l - on d.catalog_name = l.catalog_name -left outer join inferred_schemas s - on s.collection_name = l.catalog_name -where exists(select 1 from pg_roles where rolname = current_role and rolbypassrls = true) - or d.draft_id in (select id from authorized_drafts) -; -grant select on draft_specs_ext to authenticated; - -comment on view draft_specs_ext is - 'View of `draft_specs` extended with metadata of its live specification'; - -create view unchanged_draft_specs as - select - draft_id, - catalog_name, - spec_type, - live_spec_md5, - draft_spec_md5, - inferred_schema_md5, - live_inferred_schema_md5 - from draft_specs_ext d - where draft_spec_md5 = live_spec_md5 - and ( - -- either it's not a collection or it doesn't use the inferred schema - (spec_type != 'collection' or spec::text not like '%flow://inferred-schema%') - -- or the inferred schema hasn't changed since the last publication - or inferred_schema_md5 is not distinct from live_inferred_schema_md5 - ); -grant select on unchanged_draft_specs to authenticated; -comment on view unchanged_draft_specs is - 'View of `draft_specs_ext` that is filtered to only include specs that are identical to the - current `live_specs`. For collection specs that use schema inference, this will only include - them if the `inferred_schema_md5` matches the `live_inferred_schema_md5`'; - -commit; diff --git a/supabase/migrations/54_user_info_summary.sql b/supabase/migrations/54_user_info_summary.sql deleted file mode 100644 index 87f08c2218..0000000000 --- a/supabase/migrations/54_user_info_summary.sql +++ /dev/null @@ -1,27 +0,0 @@ -begin; - -create function user_info_summary() -returns json as $$ - with all_grants(role_prefix, capability) as ( - select role_prefix, capability from auth_roles() - ) - select json_build_object( - 'hasDemoAccess', exists(select 1 from all_grants where role_prefix = 'demo/' and capability >= 'read'), - 'hasSupportAccess', exists(select 1 from all_grants where role_prefix = 'estuary_support/' and capability >= 'admin'), - 'hasAnyAccess', exists(select 1 from all_grants) - ) - -$$ -language sql security invoker; - -comment on function user_info_summary is -'Returns a JSON object with a few computed attributes for the UI. -These would otherwise require the UI to fetch the complete list of authorized grants, -which can be quite slow for users with many grants. Returns a response like: -{ - hasDemoAccess: boolean, //true if the user has `read` on `demo/` tenant, - hasSupportAccess: boolean, // true if user has `admin` on `estuary_support/` - hasAnyAccess: boolean, // true if user has any authorization grants at all -}'; - -commit; diff --git a/supabase/migrations/55_inferred_schema_triggers.sql b/supabase/migrations/55_inferred_schema_triggers.sql deleted file mode 100644 index fa9e093517..0000000000 --- a/supabase/migrations/55_inferred_schema_triggers.sql +++ /dev/null @@ -1,37 +0,0 @@ --- Introduces a trigger that runs collection controllers in response to an inferred schema --- update, so that inferred schemas are published promptly in response. -begin; - -create or replace function internal.on_inferred_schema_update() -returns trigger as $$ -begin - --- The least function is necessary in order to avoid delaying a controller job in scenarios --- where there is a backlog of controller runs that are due. -update live_specs set controller_next_run = least(controller_next_run, now()) -where catalog_name = new.collection_name and spec_type = 'collection'; - -return null; -end; -$$ language plpgsql security definer; - -comment on function internal.on_inferred_schema_update is - 'Schedules a run of the controller in response to an inferred_schemas change.'; - --- We need two separate triggers because we want to reference the --- `old` row so we can avoid triggering the controller in response to --- no-op updates, which happen frequently. -create or replace trigger inferred_schema_controller_update -after update on inferred_schemas -for each row -when (old.md5 is distinct from new.md5) -execute function internal.on_inferred_schema_update(); - -create or replace trigger inferred_schema_controller_insert -after insert on inferred_schemas -for each row -execute function internal.on_inferred_schema_update(); - --- There's no `on delete` trigger because we only delete inferred_schemas by cascade from the --- live_specs deletion. -commit; diff --git a/supabase/migrations/56_delete_old_rows_faster.sql b/supabase/migrations/56_delete_old_rows_faster.sql deleted file mode 100644 index 5afd2962d6..0000000000 --- a/supabase/migrations/56_delete_old_rows_faster.sql +++ /dev/null @@ -1,79 +0,0 @@ -begin; - --- Delete old drafts, which will cascade to draft_specs, draft_errors, and discovers -create function internal.delete_old_drafts() -returns integer as $$ - with d as ( - delete from public.drafts where updated_at < (now() - '10 days'::interval) returning id - ) - select count(id) from d; -$$ language sql security definer; - -comment on function internal.delete_old_drafts is -'deletes drafts, discovers, draft_specs, and draft_errors rows that have aged out'; - -select cron.schedule( - 'delete-drafts', - '7 * * * *', -- Every hour at 7 minutes past - $$ select internal.delete_old_drafts() $$ -); - --- Delete old hourly stats -create function internal.delete_old_hourly_stats() -returns integer as $$ - with s as ( - delete from catalog_stats_hourly where grain = 'hourly' and ts < (now() - '30 days'::interval) returning ts - ) - select count(ts) from s; -$$ language sql security definer; - -comment on function internal.delete_old_hourly_stats is -'deletes catalog_stats_hourly rows that have aged out'; - -select cron.schedule( - 'delete-hourly-stats', - '19 * * * *', -- Every hour at 19 minutes past - $$ select internal.delete_old_hourly_stats() $$ -); - --- Delete old log lines -create function internal.delete_old_log_lines() -returns integer as $$ - with l as ( - delete from internal.log_lines where logged_at < (now() - '2 days'::interval) returning logged_at - ) - select count(*) from l; -$$ language sql security definer; - -comment on function internal.delete_old_log_lines is -'deletes internal.log_lines rows that have aged out'; - -select cron.schedule( - 'delete-log-lines', - '27 * * * *', -- Every hour at 27 minutes past - $$ select internal.delete_old_log_lines() $$ -); - --- The pgcron extenstion records each run in the job_run_details table. --- It does not clean these up automatically, but recommends creating a cron job to do it. --- https://github.com/citusdata/pg_cron/blob/9490f9cc9803f75105f2f7d89839a998f011f8d8/README.md#viewing-job-run-details -create function internal.delete_old_cron_runs() -returns integer as $$ - with r as ( - delete from cron.job_run_details where end_time < now() - '10 days'::interval returning runid - ) - select count(*) from r; -$$ language sql security definer; - -comment on function internal.delete_old_cron_runs is -'deletes cron.job_run_details rows that have aged out.'; - -select cron.schedule( - 'delete-job-run-details', - '0 12 * * *', -- Every day at 12:00Z - $$ select internal.delete_old_cron_runs() $$ -); - -drop function internal.delete_old_rows; - -commit; diff --git a/supabase/migrations/57_prune_unchanged_draft_specs_inferred_schemas.sql b/supabase/migrations/57_prune_unchanged_draft_specs_inferred_schemas.sql deleted file mode 100644 index eb35e34c2d..0000000000 --- a/supabase/migrations/57_prune_unchanged_draft_specs_inferred_schemas.sql +++ /dev/null @@ -1,19 +0,0 @@ -begin; - -create or replace view unchanged_draft_specs as - select - draft_id, - catalog_name, - spec_type, - live_spec_md5, - draft_spec_md5, - inferred_schema_md5, - live_inferred_schema_md5 - from draft_specs_ext d - where draft_spec_md5 = live_spec_md5; -grant select on unchanged_draft_specs to authenticated; -comment on view unchanged_draft_specs is - 'View of `draft_specs_ext` that is filtered to only include specs that are identical to the - current `live_specs`.'; - -commit; diff --git a/supabase/migrations/58_connector_tags_control_flags.sql b/supabase/migrations/58_connector_tags_control_flags.sql deleted file mode 100644 index 702164ef4a..0000000000 --- a/supabase/migrations/58_connector_tags_control_flags.sql +++ /dev/null @@ -1,11 +0,0 @@ -begin; - -alter table connector_tags add column default_capture_interval interval; -comment on column connector_tags.default_capture_interval is - 'The default value for the interval property for a Capture. This is normally used for non-streaming connectors'; - -alter table connector_tags add column disable_backfill boolean not null default false; -comment on column connector_tags.disable_backfill is - 'Controls if the UI will hide the backfill button for a connector'; - -commit; \ No newline at end of file diff --git a/supabase/migrations/59_data_planes.sql b/supabase/migrations/59_data_planes.sql deleted file mode 100644 index da2fa7541c..0000000000 --- a/supabase/migrations/59_data_planes.sql +++ /dev/null @@ -1,85 +0,0 @@ -begin; - -create table data_planes ( - like internal._model including all, - - data_plane_name catalog_name not null, - data_plane_fqdn text not null, - - ops_logs_name catalog_name not null, - ops_stats_name catalog_name not null, - - ops_l1_inferred_name catalog_name not null, - ops_l1_stats_name catalog_name not null, - ops_l2_inferred_transform text not null, - ops_l2_stats_transform text not null, - - broker_address text not null, - reactor_address text not null, - - config json not null default '{}'::json, - status json not null default '{}'::json, - logs_token uuid not null default gen_random_uuid(), - hmac_keys text[] not null, - - unique (data_plane_name), - unique (data_plane_fqdn) -); -alter table data_planes enable row level security; - -create policy "Users must be read-authorized to data planes" - on data_planes as permissive for select - using (exists( - select 1 from auth_roles('read') r where data_plane_name ^@ r.role_prefix - )); - -grant select ( - id, - data_plane_name, - data_plane_fqdn, - ops_logs_name, - ops_stats_name, - created_at, - updated_at, - broker_address, - reactor_address, - config, - status -) -on data_planes to authenticated; - - --- TODO replace with managed data-plane name for cronut. -alter table discovers add column data_plane_name text not null default 'ops/dp/public/local-cluster'; -alter table publications add column data_plane_name text not null default 'ops/dp/public/local-cluster'; - --- TODO replace with actual data-plane ID for cronut. -alter table live_specs add column data_plane_id flowid not null default '00:00:00:00:00:00:00:00'; - -create or replace function internal.task_roles( - task_name_or_prefix text, - min_capability grant_capability default 'x_00' -) -returns table (role_prefix catalog_prefix, capability grant_capability) as $$ - - with recursive - all_roles(role_prefix, capability) as ( - select g.object_role, g.capability from role_grants g - where starts_with(task_name_or_prefix, g.subject_role) - and g.capability >= min_capability - union - -- Recursive case: for each object_role granted as 'admin', - -- project through grants where object_role acts as the subject_role. - select g.object_role, g.capability - from role_grants g, all_roles a - where starts_with(a.role_prefix, g.subject_role) - and g.capability >= min_capability - and a.capability = 'admin' - ) - select role_prefix, max(capability) from all_roles - group by role_prefix - order by role_prefix; - -$$ language sql stable; - -commit; \ No newline at end of file diff --git a/supabase/migrations/60_extract_templates.sql b/supabase/migrations/60_extract_templates.sql deleted file mode 100644 index d45203743f..0000000000 --- a/supabase/migrations/60_extract_templates.sql +++ /dev/null @@ -1,14 +0,0 @@ -begin; - -alter table live_specs -add column journal_template_name text -generated always as (built_spec->'partitionTemplate'->>'name') stored; - -alter table live_specs -add column shard_template_id text -generated always as (coalesce( - built_spec->'shardTemplate'->>'id', - built_spec->'derivation'->'shardTemplate'->>'id' -)) stored; - -commit; \ No newline at end of file diff --git a/supabase/migrations/61_insert_data_plane_name.sql b/supabase/migrations/61_insert_data_plane_name.sql deleted file mode 100644 index 5b601d9853..0000000000 --- a/supabase/migrations/61_insert_data_plane_name.sql +++ /dev/null @@ -1,8 +0,0 @@ -begin; - -grant insert (draft_id, dry_run, detail, data_plane_name) on publications to authenticated; - -grant insert (capture_name, connector_tag_id, data_plane_name, draft_id, endpoint_config, update_only) - on discovers to authenticated; - -commit; \ No newline at end of file diff --git a/supabase/migrations/62_live_specs_dependencies.sql b/supabase/migrations/62_live_specs_dependencies.sql deleted file mode 100644 index 649d1a5e0b..0000000000 --- a/supabase/migrations/62_live_specs_dependencies.sql +++ /dev/null @@ -1,11 +0,0 @@ -begin; - -alter table live_specs add column dependency_hash text; - -comment on column live_specs.dependency_hash is -'An hash of all the dependencies which were used to build this spec. -Any change to the _model_ of a dependency will change this hash. -Changes to the built spec of a dependency without an accompanying -model change will not change the hash.'; - -commit; diff --git a/supabase/migrations/63_new_data_plane_columns.sql b/supabase/migrations/63_new_data_plane_columns.sql deleted file mode 100644 index df643cbbf7..0000000000 --- a/supabase/migrations/63_new_data_plane_columns.sql +++ /dev/null @@ -1,19 +0,0 @@ -begin; - -alter table data_planes add column aws_iam_user_arn text; -alter table data_planes add column cidr_blocks cidr[] not null default '{}'; -alter table data_planes add column enable_l2 boolean not null default false; -alter table data_planes add column gcp_service_account_email text; -alter table data_planes add column ssh_private_key text; - --- Must be provided explicitly. -alter table data_planes alter column enable_l2 drop default; - --- Users may read out details of applied data-plane configuration. -grant select ( - aws_iam_user_arn, - cidr_blocks, - gcp_service_account_email -) on data_planes to authenticated; - -commit; \ No newline at end of file diff --git a/supabase/migrations/64_refresh_views.sql b/supabase/migrations/64_refresh_views.sql deleted file mode 100644 index 1880b877a6..0000000000 --- a/supabase/migrations/64_refresh_views.sql +++ /dev/null @@ -1,83 +0,0 @@ -BEGIN; - -CREATE OR REPLACE VIEW live_specs_ext AS -WITH authorized_specs AS ( - SELECT l_1.id - FROM auth_roles('read'::grant_capability) r(role_prefix, capability), - live_specs l_1 - WHERE l_1.catalog_name::text ^@ r.role_prefix::text -) -SELECT - l.created_at, - l.detail, - l.id, - l.updated_at, - l.catalog_name, - l.connector_image_name, - l.connector_image_tag, - l.last_build_id, - l.last_pub_id, - l.reads_from, - l.spec, - l.spec_type, - l.writes_to, - l.built_spec, - l.md5, - l.inferred_schema_md5, - l.controller_next_run, - c.external_url AS connector_external_url, - c.id AS connector_id, - c.title AS connector_title, - c.short_description AS connector_short_description, - c.logo_url AS connector_logo_url, - c.recommended AS connector_recommended, - t.id AS connector_tag_id, - t.documentation_url AS connector_tag_documentation_url, - p.detail AS last_pub_detail, - p.user_id AS last_pub_user_id, - u.avatar_url AS last_pub_user_avatar_url, - u.email AS last_pub_user_email, - u.full_name AS last_pub_user_full_name, - l.journal_template_name, -- Added column - l.shard_template_id, -- Added column - l.data_plane_id -- Added column -FROM live_specs l -LEFT JOIN publication_specs p ON l.id::macaddr8 = p.live_spec_id::macaddr8 AND l.last_pub_id::macaddr8 = p.pub_id::macaddr8 -LEFT JOIN connectors c ON c.image_name = l.connector_image_name -LEFT JOIN connector_tags t ON c.id::macaddr8 = t.connector_id::macaddr8 AND l.connector_image_tag = t.image_tag -LEFT JOIN internal.user_profiles u ON u.user_id = p.user_id -WHERE ( - EXISTS ( - SELECT 1 - FROM pg_roles - WHERE pg_roles.rolname = CURRENT_ROLE AND pg_roles.rolbypassrls = TRUE - ) -) OR ( - l.id::macaddr8 IN ( - SELECT authorized_specs.id - FROM authorized_specs - ) -); - -CREATE OR REPLACE VIEW publication_specs_ext AS - SELECT p.live_spec_id, - p.pub_id, - p.detail, - p.published_at, - p.spec, - p.spec_type, - p.user_id, - l.catalog_name, - l.last_pub_id, - u.email AS user_email, - u.full_name AS user_full_name, - u.avatar_url AS user_avatar_url, - l.data_plane_id -- Added column - FROM publication_specs p - JOIN live_specs l ON p.live_spec_id::macaddr8 = l.id::macaddr8, - LATERAL view_user_profile(p.user_id) u(user_id, email, full_name, avatar_url); - -alter view publication_specs_ext set (security_invoker = on); -grant select on publication_specs_ext to authenticated; - -COMMIT; \ No newline at end of file diff --git a/supabase/migrations/65_extend_live_specs_view.sql b/supabase/migrations/65_extend_live_specs_view.sql deleted file mode 100644 index 4787a6da74..0000000000 --- a/supabase/migrations/65_extend_live_specs_view.sql +++ /dev/null @@ -1,66 +0,0 @@ -BEGIN; - -CREATE OR REPLACE VIEW live_specs_ext AS -WITH authorized_specs AS ( - SELECT l_1.id - FROM auth_roles('read'::grant_capability) r(role_prefix, capability), - live_specs l_1 - WHERE l_1.catalog_name::text ^@ r.role_prefix::text -) -SELECT - l.created_at, - l.detail, - l.id, - l.updated_at, - l.catalog_name, - l.connector_image_name, - l.connector_image_tag, - l.last_build_id, - l.last_pub_id, - l.reads_from, - l.spec, - l.spec_type, - l.writes_to, - l.built_spec, - l.md5, - l.inferred_schema_md5, - l.controller_next_run, - c.external_url AS connector_external_url, - c.id AS connector_id, - c.title AS connector_title, - c.short_description AS connector_short_description, - c.logo_url AS connector_logo_url, - c.recommended AS connector_recommended, - t.id AS connector_tag_id, - t.documentation_url AS connector_tag_documentation_url, - p.detail AS last_pub_detail, - p.user_id AS last_pub_user_id, - u.avatar_url AS last_pub_user_avatar_url, - u.email AS last_pub_user_email, - u.full_name AS last_pub_user_full_name, - l.journal_template_name, - l.shard_template_id, - l.data_plane_id, - d.broker_address, -- Added column - d.data_plane_name, -- Added column - d.reactor_address -- Added column -FROM live_specs l -LEFT JOIN publication_specs p ON l.id::macaddr8 = p.live_spec_id::macaddr8 AND l.last_pub_id::macaddr8 = p.pub_id::macaddr8 -LEFT JOIN connectors c ON c.image_name = l.connector_image_name -LEFT JOIN connector_tags t ON c.id::macaddr8 = t.connector_id::macaddr8 AND l.connector_image_tag = t.image_tag -LEFT JOIN internal.user_profiles u ON u.user_id = p.user_id -LEFT JOIN data_planes d ON d.id::macaddr8 = l.data_plane_id::macaddr8 -WHERE ( - EXISTS ( - SELECT 1 - FROM pg_roles - WHERE pg_roles.rolname = CURRENT_ROLE AND pg_roles.rolbypassrls = TRUE - ) -) OR ( - l.id::macaddr8 IN ( - SELECT authorized_specs.id - FROM authorized_specs - ) -); - -COMMIT; \ No newline at end of file diff --git a/supabase/migrations/66_publication_ids.sql b/supabase/migrations/66_publication_ids.sql deleted file mode 100644 index bc9110e5b4..0000000000 --- a/supabase/migrations/66_publication_ids.sql +++ /dev/null @@ -1,12 +0,0 @@ -begin; - -alter table publications add column pub_id flowid; - -comment on column publications.pub_id is -'The effective publication id that was used by the publications handler -to commit a successful publication. This will be null if the publication -did not commit. If non-null, then this is the publication id that would -exist in the publication_specs table, and would be used as the last_pub_id -for any drafted specs'; - -commit; diff --git a/supabase/migrations/67_pub_specs_perf.sql b/supabase/migrations/67_pub_specs_perf.sql deleted file mode 100644 index 6e958c2f63..0000000000 --- a/supabase/migrations/67_pub_specs_perf.sql +++ /dev/null @@ -1,35 +0,0 @@ -begin; - --- It's necessary to drop the existing view in a separate statement instead of replacing it --- because the existing view is owned by 'authenticated' and the new one must be owned by --- 'postgres' so that it bypasses RLS policies. -drop view publication_specs_ext; - -create view publication_specs_ext as -select p.live_spec_id, - p.pub_id, - p.detail, - p.published_at, - p.spec, - p.spec_type, - p.user_id, - ls.catalog_name, - ls.last_pub_id, - u.email AS user_email, - u.full_name AS user_full_name, - u.avatar_url AS user_avatar_url, - ls.data_plane_id -- Added column -from live_specs ls -join publication_specs p on ls.id = p.live_spec_id -cross join lateral view_user_profile(p.user_id) u(user_id, email, full_name, avatar_url) -where - exists ( - select 1 - from auth_roles('read'::grant_capability) r(role_prefix, capability) - where ls.catalog_name ^@ r.role_prefix - ); - --- The view performs its own authz checks -grant select on publication_specs_ext to authenticated; - -commit; diff --git a/supabase/migrations/68_capability_constraint.sql b/supabase/migrations/68_capability_constraint.sql deleted file mode 100644 index 4055ad4412..0000000000 --- a/supabase/migrations/68_capability_constraint.sql +++ /dev/null @@ -1,12 +0,0 @@ -begin; - --- Ensures that grants can only give capabilities that we actually use. --- See #1675 - -alter table user_grants add constraint valid_capability -check (capability = any(array['read'::grant_capability, 'write'::grant_capability, 'admin'::grant_capability])); - -alter table role_grants add constraint valid_capability -check (capability = any(array['read'::grant_capability, 'write'::grant_capability, 'admin'::grant_capability])); - -commit; diff --git a/supabase/migrations/README.md b/supabase/migrations/README.md new file mode 100644 index 0000000000..a61c1f7329 --- /dev/null +++ b/supabase/migrations/README.md @@ -0,0 +1,14 @@ +# Compaction + +To produce a new compaction of the production database, run: + +```bash + pg_dump ${DATABASE} \ + --exclude-table=public.flow_checkpoints_v1 \ + --exclude-table=public.flow_materializations_v2 \ + --schema internal \ + --schema public \ + --schema-only \ + | grep -v "CREATE SCHEMA public;" \ + | grep -v "ALTER DEFAULT PRIVILEGES FOR ROLE supabase_admin" +``` \ No newline at end of file diff --git a/supabase/pending/built_specs.sql b/supabase/pending/built_specs.sql deleted file mode 100644 index 7aab4bb375..0000000000 --- a/supabase/pending/built_specs.sql +++ /dev/null @@ -1,79 +0,0 @@ -begin; - -alter table live_specs add column built_spec json; -comment on column live_specs.built_spec is - 'Built specification for this catalog'; - -alter table draft_specs add column built_spec json; -alter table draft_specs add column validated json; -comment on column draft_specs.built_spec is - 'Built specification for this catalog'; -comment on column draft_specs.validated is - 'Serialized response from the connector Validate RPC as populated by a dry run of this draft specification'; - --- The live_specs_ext and draft_specs_ext views must be dropped & re-created to include their new --- columns (built_spec for live_specs_ext; built_spec & validated for draft_specs_ext) since these --- columns are included in the views from their "base" table through the "*" part of select l.*/d.* - -drop view draft_specs_ext; -drop view live_specs_ext; - --- Below here (down to the "commit;") is copied verbatim from 10_spec_ext.sql for creating the --- live_specs_ext & draft_specs_ext view. - --- Extended view of live catalog specifications. -create view live_specs_ext as -select - l.*, - c.external_url as connector_external_url, - c.id as connector_id, - c.title as connector_title, - c.short_description as connector_short_description, - c.logo_url as connector_logo_url, - c.recommended as connector_recommended, - t.id as connector_tag_id, - t.documentation_url as connector_tag_documentation_url, - p.detail as last_pub_detail, - p.user_id as last_pub_user_id, - u.avatar_url as last_pub_user_avatar_url, - u.email as last_pub_user_email, - u.full_name as last_pub_user_full_name -from live_specs l -left outer join publication_specs p on l.id = p.live_spec_id and l.last_pub_id = p.pub_id -left outer join connectors c on c.image_name = l.connector_image_name -left outer join connector_tags t on c.id = t.connector_id and l.connector_image_tag = t.image_tag -left outer join internal.user_profiles u on u.user_id = p.user_id -where l.id in ( - -- User must admin catalog_name. Compare to select RLS policy. - select l.id from auth_roles('read') r, live_specs l - where l.catalog_name ^@ r.role_prefix -) -; --- live_specs_ext includes its own authorization checks. -grant select on live_specs_ext to authenticated; - -comment on view live_specs_ext is - 'View of `live_specs` extended with metadata of its last publication'; - --- Extended view of user draft specifications. -create view draft_specs_ext as -select - d.*, - l.last_pub_detail, - l.last_pub_id, - l.last_pub_user_id, - l.last_pub_user_avatar_url, - l.last_pub_user_email, - l.last_pub_user_full_name, - l.spec as live_spec, - l.spec_type as live_spec_type -from draft_specs d -left outer join live_specs_ext l - on d.catalog_name = l.catalog_name -; -alter view draft_specs_ext owner to authenticated; - -comment on view draft_specs_ext is - 'View of `draft_specs` extended with metadata of its live specification'; - -commit; diff --git a/supabase/pending/data_planes_prod.sql b/supabase/pending/data_planes_prod.sql deleted file mode 100644 index 1104a8ba29..0000000000 --- a/supabase/pending/data_planes_prod.sql +++ /dev/null @@ -1,142 +0,0 @@ -begin; - -create table data_planes ( - like internal._model including all, - - data_plane_name catalog_name not null, - data_plane_fqdn text not null, - - ops_logs_name catalog_name not null, - ops_stats_name catalog_name not null, - - ops_l1_inferred_name catalog_name not null, - ops_l1_stats_name catalog_name not null, - ops_l2_inferred_transform text not null, - ops_l2_stats_transform text not null, - - broker_address text not null, - reactor_address text not null, - - config json not null default '{}'::json, - status json not null default '{}'::json, - logs_token uuid not null default gen_random_uuid(), - hmac_keys text[] not null, - - unique (data_plane_name), - unique (data_plane_fqdn) -); -alter table data_planes enable row level security; - -create policy "Users must be read-authorized to data planes" - on data_planes as permissive for select - using (exists( - select 1 from auth_roles('read') r where data_plane_name ^@ r.role_prefix - )); - -grant select ( - id, - data_plane_name, - data_plane_fqdn, - ops_logs_name, - ops_stats_name, - created_at, - updated_at, - broker_address, - reactor_address, - config, - status -) -on data_planes to authenticated; - -create or replace function internal.task_roles( - task_name_or_prefix text, - min_capability grant_capability default 'x_00' -) -returns table (role_prefix catalog_prefix, capability grant_capability) as $$ - - with recursive - all_roles(role_prefix, capability) as ( - select g.object_role, g.capability from role_grants g - where starts_with(task_name_or_prefix, g.subject_role) - and g.capability >= min_capability - union - -- Recursive case: for each object_role granted as 'admin', - -- project through grants where object_role acts as the subject_role. - select g.object_role, g.capability - from role_grants g, all_roles a - where starts_with(a.role_prefix, g.subject_role) - and g.capability >= min_capability - and a.capability = 'admin' - ) - select role_prefix, max(capability) from all_roles - group by role_prefix - order by role_prefix; - -$$ language sql stable; - - -alter table discovers add column data_plane_name text not null default 'ops/dp/public/gcp-us-central1-c1'; -alter table publications add column data_plane_name text not null default 'ops/dp/public/gcp-us-central1-c1'; - --- Might need to run this again, to catch any new tenants created between migration and updated agent deployment. -insert into role_grants (subject_role, object_role, capability) -select tenant, 'ops/dp/public/', 'read' from tenants -on conflict do nothing; - -do $$ -declare - cronut_id flowid; -begin - - insert into data_planes ( - data_plane_name, - data_plane_fqdn, - ops_logs_name, - ops_stats_name, - ops_l1_inferred_name, - ops_l1_stats_name, - ops_l2_inferred_transform, - ops_l2_stats_transform, - broker_address, - reactor_address, - hmac_keys - ) values ( - 'ops/dp/public/gcp-us-central1-c1', - 'gcp-us-central1-c1.dp.estuary-data.com', - 'ops.us-central1.v1/logs', - 'ops.us-central1.v1/stats', - 'ops.us-central1.v1/inferred-schemas/L1', - 'ops.us-central1.v1/catalog-stats-L1', - 'from-ops.us-central1.v1', - 'fromOps.us-central1.v1', - 'http://localhost:8080', -- TODO(johnny): K8s service - 'http://localhost:9000', -- TODO(johnny): K8s service - '{c2VjcmV0,AA==}' -- TODO(johnny): replace with actual secret. - ); - - select id into cronut_id from data_planes where data_plane_name = 'ops/dp/public/gcp-us-central1-c1'; - - execute format('alter table live_specs add column data_plane_id flowid not null default %L', cronut_id); - -end $$; - - -insert into role_grants (subject_role, object_role, capability) values - -- L1 roll-ups can read task logs & stats. - ('ops/rollups/L1/', 'ops/tasks/', 'read'), - -- L1 roll-ups tasks can write to themselves. - ('ops/rollups/L1/', 'ops/rollups/L1/', 'write'), - -- L2 roll-ups can read L1 roll-ups. - ('ops.us-central1.v1/', 'ops/rollups/L1/', 'read') - ; - --- Ops collections are directed to estuary-flow-poc and not estuary-trial for $reasons. -insert into storage_mappings (catalog_prefix, spec) values - ('ops/', '{"stores": [{"provider": "GCS", "bucket": "estuary-flow-poc", "prefix": "collection-data/"}]}'), - ('recovery/ops/', '{"stores": [{"provider": "GCS", "bucket": "estuary-flow-poc"}]}') -; - -insert into user_grants (user_id, object_role, capability) -select id, 'ops/', 'admin' from auth.users where email = 'support@estuary.dev'; - -commit; diff --git a/supabase/seed.sql b/supabase/seed.sql index 5dbe4ec1f2..8c3eac9100 100644 --- a/supabase/seed.sql +++ b/supabase/seed.sql @@ -11,30 +11,8 @@ insert into auth.users (id, email) values ('44444444-4444-4444-4444-444444444444', 'dave@example.com') ; --- Tweak auth.users to conform with what a local Supabase install creates --- if you perform the email "Sign Up" flow. In development mode it --- doesn't actually send an email, and immediately creates a record like this: -update auth.users set - "role" = 'authenticated', - aud = 'authenticated', - confirmation_token = '', - created_at = now(), - email_change = '', - email_change_confirm_status = 0, - email_change_token_new = '', - email_confirmed_at = now(), - encrypted_password = '$2a$10$vQCyRoGamfEBXOR05iNgseK.ukEUPV52W1B95Qt6Tb3kN4N32odji', -- "password" - instance_id = '00000000-0000-0000-0000-000000000000', - is_super_admin = false, - last_sign_in_at = now(), - raw_app_meta_data = '{"provider": "email", "providers": ["email"]}', - raw_user_meta_data = '{}', - recovery_token = '', - updated_at = now() -; - -- Public directive which allows a new user to provision a new tenant. -insert into directives (catalog_prefix, spec, token) values +insert into public.directives (catalog_prefix, spec, token) values ('ops/', '{"type":"clickToAccept"}', 'd4a37dd7-1bf5-40e3-b715-60c4edd0f6dc'), ('ops/', '{"type":"betaOnboard"}', '453e00cd-e12a-4ce5-b12d-3837aa385751'), ('ops/', '{"type":"acceptDemoTenant"}', '14c0beec-422f-4e95-94f1-567107b26840'); @@ -43,12 +21,12 @@ insert into directives (catalog_prefix, spec, token) values with accounts_root_user as ( select (select id from auth.users where email = 'support@estuary.dev' limit 1) as accounts_id ) -insert into applied_directives (directive_id, user_id, user_claims) +insert into public.applied_directives (directive_id, user_id, user_claims) select d.id, a.accounts_id, '{"requestedTenant":"ops.us-central1.v1"}' - from directives d, accounts_root_user a + from public.directives d, accounts_root_user a where catalog_prefix = 'ops/' and spec = '{"type":"betaOnboard"}'; -insert into role_grants (subject_role, object_role, capability) values +insert into public.role_grants (subject_role, object_role, capability) values -- L1 roll-ups can read task logs & stats. ('ops/rollups/L1/', 'ops/tasks/', 'read'), -- L1 roll-ups tasks can write to themselves. @@ -60,7 +38,7 @@ insert into role_grants (subject_role, object_role, capability) values ; -- Ops collections are directed to estuary-flow-poc and not estuary-trial for $reasons. -insert into storage_mappings (catalog_prefix, spec) values +insert into public.storage_mappings (catalog_prefix, spec) values ('ops/', '{"stores": [{"provider": "GCS", "bucket": "estuary-flow-poc", "prefix": "collection-data/"}]}'), ('recovery/ops/', '{"stores": [{"provider": "GCS", "bucket": "estuary-flow-poc"}]}'), -- For access within local stack contexts: @@ -69,7 +47,7 @@ insert into storage_mappings (catalog_prefix, spec) values ; -- Give support@estuary.dev the admin role for `ops/` and `ops.us-central1.v1/` management. -insert into user_grants (user_id, object_role, capability) values +insert into public.user_grants (user_id, object_role, capability) values -- TODO: estuary_support/ is currently required for control-plane automation. -- We should instead explicitly check for `system_user_id`. ('ffffffff-ffff-ffff-ffff-ffffffffffff', 'estuary_support/', 'admin'), @@ -83,40 +61,51 @@ insert into user_grants (user_id, object_role, capability) values -- production connectors, because each is pulled onto your dev machine. do $$ declare - connector_id flowid; + connector_id public.flowid; begin - insert into connectors (image_name, title, short_description, logo_url, external_url) values ( + insert into public.connectors (image_name, title, short_description, logo_url, external_url, recommended) values ( 'ghcr.io/estuary/source-hello-world', json_build_object('en-US','Hello World'), json_build_object('en-US','A flood of greetings'), json_build_object('en-US','https://www.estuary.dev/wp-content/uploads/2022/05/Group-4-300x300.png'), - 'https://estuary.dev' + 'https://estuary.dev', + true ) returning id strict into connector_id; - insert into connector_tags (connector_id, image_tag) values (connector_id, ':dev'); + insert into public.connector_tags (connector_id, image_tag) values (connector_id, ':dev'); - insert into connectors (image_name, title, short_description, logo_url, external_url) values ( + insert into public.connectors (image_name, title, short_description, logo_url, external_url, recommended) values ( 'ghcr.io/estuary/source-postgres', json_build_object('en-US','PostgreSQL'), json_build_object('en-US','Capture PostgreSQL tables into collections'), json_build_object('en-US','https://www.postgresql.org/media/img/about/press/elephant.png'), - 'https://postgresql.org' + 'https://postgresql.org', + true ) returning id strict into connector_id; - insert into connector_tags (connector_id, image_tag) values (connector_id, ':dev'); + insert into public.connector_tags (connector_id, image_tag) values (connector_id, ':dev'); - insert into connectors (image_name, title, short_description, logo_url, external_url) values ( + insert into public.connectors (image_name, title, short_description, logo_url, external_url, recommended) values ( 'ghcr.io/estuary/materialize-postgres', json_build_object('en-US','PostgreSQL'), json_build_object('en-US','Materialize collections into PostgreSQL'), json_build_object('en-US','https://www.postgresql.org/media/img/about/press/elephant.png'), - 'https://postgresql.org' + 'https://postgresql.org', + true ) returning id strict into connector_id; - insert into connector_tags (connector_id, image_tag) values (connector_id, ':dev'); + insert into public.connector_tags (connector_id, image_tag) values (connector_id, ':dev'); end; $$ language plpgsql; +-- TODO(johnny): Support deprecated gateway_auth_token() RPC to be removed: +insert into internal.gateway_auth_keys (secret_key, detail) values ( + 'supersecret', 'Used for development only. This value will be changed manually when deployed to production.' +); +insert into internal.gateway_endpoints (name, url, detail) values ( + 'local', 'https://localhost:28318/', 'Used for development only. This value will be changed manually when deployed to production.' +); + commit; diff --git a/supabase/tests/auto_discovers.test.sql b/supabase/tests/auto_discovers.test.sql index 226359d592..5c8e7622a7 100644 --- a/supabase/tests/auto_discovers.test.sql +++ b/supabase/tests/auto_discovers.test.sql @@ -14,8 +14,8 @@ begin -- insert into user_grants (user_id, object_role, capability) values -- ('11111111-1111-1111-1111-111111111111', 'estuary_support/', 'admin'); insert into tenants (tenant) values ('aliceCo/'); - insert into connectors (id, image_name, title, short_description, logo_url, external_url) values - ('12:34:56:78:87:65:43:21', 'captureImage', '{"en-US":"a title"}', '{"en-US":"a desc"}', '{"en-US":"a logo"}', 'http://foo.test'); + insert into connectors (id, image_name, title, short_description, logo_url, external_url, recommended) values + ('12:34:56:78:87:65:43:21', 'captureImage', '{"en-US":"a title"}', '{"en-US":"a desc"}', '{"en-US":"a logo"}', 'http://foo.test', true); insert into connector_tags (connector_id, image_tag) values ('12:34:56:78:87:65:43:21', ':v0'); insert into live_specs (catalog_name, spec_type, spec, connector_image_name, connector_image_tag, updated_at) values diff --git a/supabase/tests/delete_old_rows.test.sql b/supabase/tests/delete_old_rows.test.sql index 882f24e046..12adfc80e9 100644 --- a/supabase/tests/delete_old_rows.test.sql +++ b/supabase/tests/delete_old_rows.test.sql @@ -10,9 +10,9 @@ declare begin insert into auth.users(id, email) values (test_user_id, 'test@test.test'); - insert into connectors (id, image_name, title, short_description, logo_url, external_url) values + insert into connectors (id, image_name, title, short_description, logo_url, external_url, recommended) values ('33:33:33:33:33:33:33:97', 'captureImage', '{"en-US":"a title"}', '{"en-US":"a desc"}', - '{"en-US":"a logo"}', 'http://foo.test'); + '{"en-US":"a logo"}', 'http://foo.test', true); insert into connector_tags (id, connector_id, image_tag) values (test_connector_tag_id, '33:33:33:33:33:33:33:97', ':v0');