--! Previous: - --! Hash: sha1:b13a5217288f5d349d8d9e3afbd7bb30c0dbad21 -- region Bootstrap drop schema if exists app_public cascade; alter default privileges revoke all on sequences from public; alter default privileges revoke all on functions from public; -- By default the public schema is owned by `postgres`; we need superuser privileges to change this :( -- alter schema public owner to waterbear; revoke all on schema public from public; grant all on schema public to :DATABASE_OWNER; create schema app_public; grant usage on schema public, app_public to :DATABASE_VISITOR, app_admin, app_anonymous, app_user; /**********/ drop schema if exists app_hidden cascade; create schema app_hidden; grant usage on schema app_hidden to :DATABASE_VISITOR; alter default privileges in schema app_hidden grant usage, select on sequences to :DATABASE_VISITOR; /**********/ alter default privileges in schema public, app_public, app_hidden grant usage, select on sequences to :DATABASE_VISITOR; alter default privileges in schema public, app_public, app_hidden grant execute on functions to :DATABASE_VISITOR, app_admin, app_user; /**********/ drop schema if exists app_private cascade; create schema app_private; -- endregion -- region UtilFunctions create function app_private.tg__add_job() returns trigger as $$ begin perform graphile_worker.add_job(tg_argv[0], json_build_object('id', NEW.id), coalesce(tg_argv[1], public.gen_random_uuid()::text)); return NEW; end; $$ language plpgsql volatile security definer set search_path to pg_catalog, public, pg_temp; comment on function app_private.tg__add_job() is E'Useful shortcut to create a job on insert/update. Pass the task name as the first trigger argument, and optionally the queue name as the second argument. The record id will automatically be available on the JSON payload.'; /* ------------------------------------------------------------------ */ create function app_private.tg__timestamps() returns trigger as $$ begin NEW.created_at = (case when TG_OP = 'INSERT' then NOW() else OLD.created_at end); NEW.updated_at = (case when TG_OP = 'UPDATE' and OLD.updated_at >= NOW() then OLD.updated_at + interval '1 millisecond' else NOW() end); return NEW; end; $$ language plpgsql volatile set search_path to pg_catalog, public, pg_temp; comment on function app_private.tg__timestamps() is E'This trigger should be called on all tables with created_at, updated_at - it ensures that they cannot be manipulated and that updated_at will always be larger than the previous updated_at.'; -- endregion -- region Users, Sessions, and Accounts /* ------------------------------------------------------------------ */ create table app_private.sessions ( id uuid not null default gen_random_uuid() primary key, user_id uuid not null, expires timestamptz not null, session_token text not null, access_token text not null, created_at timestamptz not null default now(), updated_at timestamptz not null default now(), last_active_at timestamptz not null default now() ); create unique index session_token on app_private.sessions(session_token); create unique index access_token on app_private.sessions(access_token); alter table app_private.sessions enable row level security; /* ------------------------------------------------------------------ */ create function app_public.current_session_id() returns uuid as $$ -- note the jwt.claims.session_id doesn't mean you have to use jwt, it is just where this function will always look for the session id. select nullif(pg_catalog.current_setting('jwt.claims.session_id', true), '')::uuid; $$ language sql stable; comment on function app_public.current_session_id() is E'Handy method to get the current session ID.'; /* * A less secure but more performant version of this function would be just: * * select nullif(pg_catalog.current_setting('jwt.claims.user_id', true), '')::int; * * The increased security of this implementation is because even if someone gets * the ability to run SQL within this transaction they cannot impersonate * another user without knowing their session_id (which should be closely * guarded). */ create function app_public.current_user_id() returns uuid as $$ select user_id from app_private.sessions where id = app_public.current_session_id(); $$ language sql stable security definer set search_path to pg_catalog, public, pg_temp; comment on function app_public.current_user_id() is E'Handy method to get the current user ID for use in RLS policies, etc; in GraphQL, use `currentUser{id}` instead.'; -- We've put this in public, but omitted it, because it's often useful for debugging auth issues. /* ------------------------------------------------------------------ */ -- These are the user roles for our application create type app_public.role_type as ENUM ('none','admin', 'user'); /* ------------------------------------------------------------------ */ create table app_public.users ( id uuid not null default uuid_generate_v1mc() primary key, email citext not null, email_verified timestamptz, name text not null, avatar text, user_role app_public.role_type not null default 'none', is_active boolean not null default false, created_at timestamptz not null default now(), updated_at timestamptz not null default now(), created_by text not null, constraint users_email_validity check (email ~* '^[A-Za-z0-9._%-]+@[A-Za-z0-9.-]+[.][A-Za-z]+$'), constraint users_avatar_validity check (avatar ~ '^https?://[^/]+'), constraint users_email_unique unique (email) ); comment on table app_public.users is E'A user who can log in to the application.'; comment on column app_public.users.id is E'Unique identifier for the user.'; comment on column app_public.users.email is E'The email address of the user.'; comment on column app_public.users.email_verified is E'The time at which the email address was verified'; comment on column app_public.users.name is E'Public-facing name (or pseudonym) of the user.'; comment on column app_public.users.avatar is E'Optional avatar URL.'; comment on column app_public.users.user_role is E'The role that defines the user''s privileges.'; comment on column app_public.users.is_active is E'If false, the user is not allowed to login or access the application'; alter table app_public.users enable row level security; alter table app_private.sessions add constraint sessions_user_id_fkey foreign key ("user_id") references app_public.users on delete cascade; create index on app_private.sessions (user_id); -- app_public perms default create policy access_self on app_public.users to app_anonymous using (id = app_public.current_user_id()); --create policy update_self on app_public.users for update using (id = app_public.current_user_id()); grant select on app_public.users to app_anonymous; grant update (name, avatar) on app_public.users to :DATABASE_VISITOR, app_user; -- app_public perms for app_admin create policy access_all on app_public.users to app_admin using (true); grant update (email, name, avatar, is_active, user_role) on app_public.users to app_admin; grant select on app_public.users to app_admin; grant insert (email, name, avatar, user_role, is_active, created_by) on app_public.users to app_admin; grant update (email, name, avatar, user_role, is_active, created_by) on app_public.users to app_admin; create trigger _100_timestamps before insert or update on app_public.users for each row execute procedure app_private.tg__timestamps(); /* ------------------------------------------------------------------ */ create function app_public.current_user() returns app_public.users as $$ select users.* from app_public.users where id = app_public.current_user_id(); $$ language sql stable; comment on function app_public.current_user() is E'The currently logged in user (or null if not logged in).'; /* ------------------------------------------------------------------ */ create function app_public.logout() returns void as $$ begin -- Delete the session delete from app_private.sessions where id = app_public.current_session_id(); -- Clear the identifier from the transaction perform set_config('jwt.claims.session_id', '', true); end; $$ language plpgsql security definer volatile set search_path to pg_catalog, public, pg_temp; /* ------------------------------------------------------------------ */ create table app_public.accounts ( id uuid not null default uuid_generate_v1mc() primary key, compound_id text not null, user_id uuid not null, provider_type text not null, provider_id text not null, provider_account_id text not null, refresh_token text, access_token text, access_token_expires timestamptz, created_at timestamptz not null default now(), updated_at timestamptz not null default now() ); alter table app_public.accounts enable row level security; alter table app_public.accounts add constraint accounts_user_id_fkey foreign key ("user_id") references app_public.users on delete cascade; create unique index accounts_compound_id on app_public.accounts(compound_id); create index accounts_provider_account_id on app_public.accounts(provider_account_id); create index accounts_provider_id on app_public.accounts(provider_id); create index accounts_user_id on app_public.accounts (user_id); create policy access_self on app_public.accounts to app_anonymous using (user_id = app_public.current_user_id()); grant select on app_public.accounts to app_anonymous; grant update (compound_id, provider_type, provider_id, provider_account_id, refresh_token, access_token, access_token_expires) on app_public.accounts to app_user; create policy access_all on app_public.accounts to app_admin using (true); grant update (compound_id, provider_type, provider_id, provider_account_id, refresh_token, access_token, access_token_expires) on app_public.accounts to app_admin; grant select on app_public.accounts to app_admin; grant insert (user_id, compound_id, provider_type, provider_id, provider_account_id, refresh_token, access_token, access_token_expires) on app_public.accounts to app_admin; grant update (compound_id, provider_type, provider_id, provider_account_id, refresh_token, access_token, access_token_expires) on app_public.accounts to app_admin; create trigger _100_timestamps before insert or update on app_public.accounts for each row execute procedure app_private.tg__timestamps(); -- endregion -- region Create first user function create or replace function app_public.create_first_user (user_email text, user_name text) returns setof app_public.users as $$ declare user_count int; begin user_count := (select count(id) from app_public.users); if (user_count != 0) then raise exception 'Admin user already created'; end if; return query insert into app_public.users (email, email_verified, name, user_role, is_active, created_by) values (user_email, now(), user_name, 'admin', true, 'first user hook') returning *; end ; $$ LANGUAGE plpgsql VOLATILE SECURITY DEFINER; comment on function app_public.create_first_user(user_email text, user_name text) is E'Creates the first user with an admin role. Only possible when there are no other users in the database.'; grant execute on function app_public.create_first_user(user_email text, user_name text) to app_anonymous; create function app_private.tg__first_user() returns trigger as $$ declare user_count int; begin user_count := (select count(id) from app_public.users); if (user_count = 0) then NEW.user_role = 'admin'; end if; return NEW; end; $$ language plpgsql volatile set search_path to pg_catalog, public, pg_temp; comment on function app_private.tg__first_user() is E'This trigger is called to ensure the first user created is an admin'; create trigger _101_first_user before insert on app_public.users for each row execute procedure app_private.tg__first_user(); -- endregion -- region Settings create table app_public.settings ( id uuid not null default uuid_generate_v1mc() primary key, name text not null, value jsonb, created_at timestamptz not null default now(), updated_at timestamptz not null default now() ); create unique index setting_name on app_public.settings(name); alter table app_public.settings enable row level security; create policy access_all on app_public.settings to app_admin using (true); grant update (name, value) on app_public.settings to app_admin; grant select on app_public.settings to app_admin; grant insert (name, value) on app_public.settings to app_admin; create trigger _100_timestamps before insert or update on app_public.settings for each row execute procedure app_private.tg__timestamps(); -- endregion -- region Provider create table app_public.voice_providers ( id uuid not null default uuid_generate_v1mc() primary key, kind text not null, name text not null, credentials jsonb not null, created_at timestamptz not null default now(), updated_at timestamptz not null default now() ); create unique index voice_providers_number on app_public.voice_providers(name); alter table app_public.voice_providers enable row level security; create policy access_all on app_public.voice_providers to app_admin using (true); grant update (name, credentials) on app_public.voice_providers to app_admin; grant select on app_public.voice_providers to app_admin; grant insert (kind, name, credentials) on app_public.voice_providers to app_admin; grant delete on app_public.voice_providers to app_admin; create trigger _100_timestamps before insert or update on app_public.voice_providers for each row execute procedure app_private.tg__timestamps(); -- endregion -- region Voice Line create table app_public.voice_lines ( id uuid not null default uuid_generate_v1mc() primary key, provider_id uuid not null, provider_line_sid text not null, number text not null, language text not null, voice text not null, prompt_text text, prompt_audio jsonb, audio_prompt_enabled boolean not null default false, audio_converted_at timestamptz, created_at timestamptz not null default now(), updated_at timestamptz not null default now() ); alter table app_public.voice_lines add constraint voice_lines_provider_id_fkey foreign key ("provider_id") references app_public.voice_providers on delete cascade; create index on app_public.voice_lines (provider_id); create index on app_public.voice_lines (provider_line_sid); create unique index voice_lines_number on app_public.voice_lines(number); alter table app_public.voice_lines enable row level security; create policy access_all on app_public.voice_lines to app_admin using (true); grant update (prompt_text, prompt_audio, audio_prompt_enabled, language, voice) on app_public.voice_lines to app_admin; grant select on app_public.voice_lines to app_admin; grant insert (provider_id, provider_line_sid, number, prompt_text, prompt_audio, audio_prompt_enabled, language, voice) on app_public.voice_lines to app_admin; grant delete on app_public.voice_lines to app_admin; create trigger _100_timestamps before insert or update on app_public.voice_lines for each row execute procedure app_private.tg__timestamps(); create function app_private.tg__voice_line_provider_update() returns trigger as $$ begin if (TG_OP = 'DELETE') then perform graphile_worker.add_job('voice-line-delete', json_build_object('voiceLineId', OLD.id, 'providerId', OLD.provider_id, 'providerLineSid', OLD.provider_line_sid)); else perform graphile_worker.add_job('voice-line-provider-update', json_build_object('voiceLineId', NEW.id)); end if; return null; end; $$ language plpgsql volatile security definer set search_path to pg_catalog, public, pg_temp; comment on function app_private.tg__voice_line_provider_update() is E'This trigger is called to ensure a voice line is connected to twilio properly'; create trigger _101_voice_line_provider_update after insert or update of provider_line_sid or delete on app_public.voice_lines for each row execute procedure app_private.tg__voice_line_provider_update(); create function app_private.tg__voice_line_prompt_audio_update() returns trigger as $$ begin perform graphile_worker.add_job('voice-line-audio-update', json_build_object('voiceLineId', NEW.id)); return null; end; $$ language plpgsql volatile security definer set search_path to pg_catalog, public, pg_temp; comment on function app_private.tg__voice_line_prompt_audio_update() is E'This trigger is called to ensure a voice line is connected to twilio properly'; create trigger _101_voice_line_prompt_audio_update after insert or update of prompt_audio on app_public.voice_lines for each row execute procedure app_private.tg__voice_line_prompt_audio_update(); -- endregion -- region Webhooks create table app_public.webhooks ( id uuid not null default uuid_generate_v1mc() primary key, backend_type text not null, backend_id uuid not null, name text not null, endpoint_url text not null, http_method text not null default 'post', headers jsonb, created_at timestamptz not null default now(), updated_at timestamptz not null default now(), constraint webhook_http_method_validity check (http_method in ('post', 'put')), constraint webhook_endpoint_url_validity check (endpoint_url ~ '^https?://[^/]+') ); create index on app_public.webhooks (backend_type, backend_id); alter table app_public.webhooks enable row level security; create policy access_all on app_public.webhooks to app_admin using (true); grant update (name, endpoint_url, http_method, headers) on app_public.webhooks to app_admin; grant select on app_public.webhooks to app_admin; grant insert (backend_type, backend_id, name, endpoint_url, http_method, headers) on app_public.webhooks to app_admin; grant delete on app_public.webhooks to app_admin; create trigger _100_timestamps before insert or update on app_public.webhooks for each row execute procedure app_private.tg__timestamps(); -- endregion -- region WhatsappBots set transform_null_equals to true; create table app_public.whatsapp_bots ( id uuid not null default uuid_generate_v1mc() primary key, phone_number text not null, token uuid not null default uuid_generate_v1mc(), user_id uuid not null, description text, auth_info text, qr_code text, is_verified boolean not null default false, created_at timestamptz not null default now(), updated_at timestamptz not null default now() ); create unique index whatsapp_bot_token on app_public.whatsapp_bots(token); alter table app_public.whatsapp_bots add constraint whatsapp_bots_user_id_fkey foreign key ("user_id") references app_public.users on delete cascade; alter table app_public.whatsapp_bots enable row level security; create policy access_all on app_public.whatsapp_bots to app_admin using (true); grant update (phone_number, token, user_id, description, auth_info, qr_code, is_verified) on app_public.whatsapp_bots to app_admin; grant select on app_public.whatsapp_bots to app_admin; grant insert (phone_number, token, user_id, description, auth_info, qr_code, is_verified) on app_public.whatsapp_bots to app_admin; create trigger _100_timestamps before insert or update on app_public.whatsapp_bots for each row execute procedure app_private.tg__timestamps(); -- endregion -- region WhatsappMessages create table app_public.whatsapp_messages ( id uuid not null default uuid_generate_v1mc() primary key, whatsapp_bot_id uuid not null, wa_message_id text, wa_message text, wa_timestamp timestamptz, created_at timestamptz not null default now(), updated_at timestamptz not null default now() ); create unique index whatsapp_message_whatsapp_bot_id on app_public.whatsapp_messages(whatsapp_bot_id); alter table app_public.whatsapp_messages add constraint whatsapp_messages_whatsapp_bot_id_fkey foreign key ("whatsapp_bot_id") references app_public.whatsapp_bots on delete cascade; alter table app_public.whatsapp_messages enable row level security; create policy access_all on app_public.whatsapp_messages to app_admin using (true); grant update (whatsapp_bot_id, wa_message_id, wa_message, wa_timestamp) on app_public.whatsapp_messages to app_admin; grant select on app_public.whatsapp_messages to app_admin; grant insert (whatsapp_bot_id, wa_message_id, wa_message, wa_timestamp) on app_public.whatsapp_messages to app_admin; create trigger _100_timestamps before insert or update on app_public.whatsapp_messages for each row execute procedure app_private.tg__timestamps(); -- endregion -- region WhatsappAttachments create table app_public.whatsapp_attachments ( id uuid not null default uuid_generate_v1mc() primary key, whatsapp_bot_id uuid not null, whatsapp_message_id uuid, attachment bytea, created_at timestamptz not null default now(), updated_at timestamptz not null default now() ); create unique index whatsapp_attachment_whatsapp_bot_id on app_public.whatsapp_attachments(whatsapp_bot_id); create unique index whatsapp_attachment_whatsapp_message_id on app_public.whatsapp_attachments(whatsapp_message_id); alter table app_public.whatsapp_attachments add constraint whatsapp_attachments_whatsapp_bot_id_fkey foreign key ("whatsapp_bot_id") references app_public.whatsapp_bots on delete cascade; alter table app_public.whatsapp_attachments add constraint whatsapp_attachments_whatsapp_message_id_fkey foreign key ("whatsapp_message_id") references app_public.whatsapp_messages on delete cascade; alter table app_public.whatsapp_attachments enable row level security; create policy access_all on app_public.whatsapp_attachments to app_admin using (true); grant update (whatsapp_bot_id, whatsapp_message_id, attachment) on app_public.whatsapp_attachments to app_admin; grant select on app_public.whatsapp_attachments to app_admin; grant insert (whatsapp_bot_id, whatsapp_message_id, attachment) on app_public.whatsapp_attachments to app_admin; create trigger _100_timestamps before insert or update on app_public.whatsapp_attachments for each row execute procedure app_private.tg__timestamps(); -- endregion -- region SignalBots set transform_null_equals to true; create table app_public.signal_bots ( id uuid not null default uuid_generate_v1mc() primary key, phone_number text not null, token uuid not null default uuid_generate_v1mc(), user_id uuid not null, description text, auth_info text, is_verified boolean not null default false, created_at timestamptz not null default now(), updated_at timestamptz not null default now() ); create unique index signal_bot_token on app_public.signal_bots(token); alter table app_public.signal_bots add constraint signal_bots_user_id_fkey foreign key ("user_id") references app_public.users on delete cascade; alter table app_public.signal_bots enable row level security; create policy access_all on app_public.signal_bots to app_admin using (true); grant update (phone_number, token, user_id, description, auth_info, is_verified) on app_public.signal_bots to app_admin; grant select on app_public.signal_bots to app_admin; grant insert (phone_number, token, user_id, description, auth_info, is_verified) on app_public.signal_bots to app_admin; create trigger _100_timestamps before insert or update on app_public.signal_bots for each row execute procedure app_private.tg__timestamps(); -- endregion