Skip to content

Commit 94d5268

Browse files
committed
readd migration
1 parent 23e24b4 commit 94d5268

File tree

3 files changed

+12795
-0
lines changed

3 files changed

+12795
-0
lines changed
Lines changed: 365 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,365 @@
1+
-- ============================================================
2+
-- Triggers for user_table_rows (from 0156 schema addition)
3+
-- Drizzle does not generate trigger SQL, so they are applied here.
4+
-- ============================================================
5+
6+
CREATE OR REPLACE FUNCTION increment_user_table_row_count()
7+
RETURNS TRIGGER AS $$
8+
DECLARE
9+
current_count INTEGER;
10+
max_allowed INTEGER;
11+
BEGIN
12+
SELECT row_count, max_rows INTO current_count, max_allowed
13+
FROM user_table_definitions
14+
WHERE id = NEW.table_id;
15+
16+
IF current_count >= max_allowed THEN
17+
RAISE EXCEPTION 'Maximum row limit (%) reached for table %', max_allowed, NEW.table_id;
18+
END IF;
19+
20+
UPDATE user_table_definitions
21+
SET row_count = row_count + 1,
22+
updated_at = now()
23+
WHERE id = NEW.table_id;
24+
25+
RETURN NEW;
26+
END;
27+
$$ LANGUAGE plpgsql;
28+
--> statement-breakpoint
29+
30+
CREATE OR REPLACE FUNCTION decrement_user_table_row_count()
31+
RETURNS TRIGGER AS $$
32+
BEGIN
33+
UPDATE user_table_definitions
34+
SET row_count = GREATEST(row_count - 1, 0),
35+
updated_at = now()
36+
WHERE id = OLD.table_id;
37+
38+
RETURN OLD;
39+
END;
40+
$$ LANGUAGE plpgsql;
41+
--> statement-breakpoint
42+
43+
CREATE TRIGGER user_table_rows_insert_trigger
44+
BEFORE INSERT ON user_table_rows
45+
FOR EACH ROW
46+
EXECUTE FUNCTION increment_user_table_row_count();
47+
--> statement-breakpoint
48+
49+
CREATE TRIGGER user_table_rows_delete_trigger
50+
AFTER DELETE ON user_table_rows
51+
FOR EACH ROW
52+
EXECUTE FUNCTION decrement_user_table_row_count();
53+
--> statement-breakpoint
54+
55+
-- ============================================================
56+
-- Credential system schema + backfill
57+
-- ============================================================
58+
59+
CREATE TYPE "public"."credential_member_role" AS ENUM('admin', 'member');--> statement-breakpoint
60+
CREATE TYPE "public"."credential_member_status" AS ENUM('active', 'pending', 'revoked');--> statement-breakpoint
61+
CREATE TYPE "public"."credential_type" AS ENUM('oauth', 'env_workspace', 'env_personal');--> statement-breakpoint
62+
CREATE TABLE "credential" (
63+
"id" text PRIMARY KEY NOT NULL,
64+
"workspace_id" text NOT NULL,
65+
"type" "credential_type" NOT NULL,
66+
"display_name" text NOT NULL,
67+
"description" text,
68+
"provider_id" text,
69+
"account_id" text,
70+
"env_key" text,
71+
"env_owner_user_id" text,
72+
"created_by" text NOT NULL,
73+
"created_at" timestamp DEFAULT now() NOT NULL,
74+
"updated_at" timestamp DEFAULT now() NOT NULL,
75+
CONSTRAINT "credential_oauth_source_check" CHECK ((type <> 'oauth') OR (account_id IS NOT NULL AND provider_id IS NOT NULL)),
76+
CONSTRAINT "credential_workspace_env_source_check" CHECK ((type <> 'env_workspace') OR (env_key IS NOT NULL AND env_owner_user_id IS NULL)),
77+
CONSTRAINT "credential_personal_env_source_check" CHECK ((type <> 'env_personal') OR (env_key IS NOT NULL AND env_owner_user_id IS NOT NULL))
78+
);
79+
--> statement-breakpoint
80+
CREATE TABLE "credential_member" (
81+
"id" text PRIMARY KEY NOT NULL,
82+
"credential_id" text NOT NULL,
83+
"user_id" text NOT NULL,
84+
"role" "credential_member_role" DEFAULT 'member' NOT NULL,
85+
"status" "credential_member_status" DEFAULT 'active' NOT NULL,
86+
"joined_at" timestamp,
87+
"invited_by" text,
88+
"created_at" timestamp DEFAULT now() NOT NULL,
89+
"updated_at" timestamp DEFAULT now() NOT NULL
90+
);
91+
--> statement-breakpoint
92+
CREATE TABLE "pending_credential_draft" (
93+
"id" text PRIMARY KEY NOT NULL,
94+
"user_id" text NOT NULL,
95+
"workspace_id" text NOT NULL,
96+
"provider_id" text NOT NULL,
97+
"display_name" text NOT NULL,
98+
"description" text,
99+
"credential_id" text,
100+
"expires_at" timestamp NOT NULL,
101+
"created_at" timestamp DEFAULT now() NOT NULL
102+
);
103+
--> statement-breakpoint
104+
DROP INDEX "account_user_provider_unique";--> statement-breakpoint
105+
ALTER TABLE "credential" ADD CONSTRAINT "credential_workspace_id_workspace_id_fk" FOREIGN KEY ("workspace_id") REFERENCES "public"."workspace"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
106+
ALTER TABLE "credential" ADD CONSTRAINT "credential_account_id_account_id_fk" FOREIGN KEY ("account_id") REFERENCES "public"."account"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
107+
ALTER TABLE "credential" ADD CONSTRAINT "credential_env_owner_user_id_user_id_fk" FOREIGN KEY ("env_owner_user_id") REFERENCES "public"."user"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
108+
ALTER TABLE "credential" ADD CONSTRAINT "credential_created_by_user_id_fk" FOREIGN KEY ("created_by") REFERENCES "public"."user"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
109+
ALTER TABLE "credential_member" ADD CONSTRAINT "credential_member_credential_id_credential_id_fk" FOREIGN KEY ("credential_id") REFERENCES "public"."credential"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
110+
ALTER TABLE "credential_member" ADD CONSTRAINT "credential_member_user_id_user_id_fk" FOREIGN KEY ("user_id") REFERENCES "public"."user"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
111+
ALTER TABLE "credential_member" ADD CONSTRAINT "credential_member_invited_by_user_id_fk" FOREIGN KEY ("invited_by") REFERENCES "public"."user"("id") ON DELETE set null ON UPDATE no action;--> statement-breakpoint
112+
ALTER TABLE "pending_credential_draft" ADD CONSTRAINT "pending_credential_draft_user_id_user_id_fk" FOREIGN KEY ("user_id") REFERENCES "public"."user"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
113+
ALTER TABLE "pending_credential_draft" ADD CONSTRAINT "pending_credential_draft_workspace_id_workspace_id_fk" FOREIGN KEY ("workspace_id") REFERENCES "public"."workspace"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
114+
ALTER TABLE "pending_credential_draft" ADD CONSTRAINT "pending_credential_draft_credential_id_credential_id_fk" FOREIGN KEY ("credential_id") REFERENCES "public"."credential"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
115+
CREATE INDEX "credential_workspace_id_idx" ON "credential" USING btree ("workspace_id");--> statement-breakpoint
116+
CREATE INDEX "credential_type_idx" ON "credential" USING btree ("type");--> statement-breakpoint
117+
CREATE INDEX "credential_provider_id_idx" ON "credential" USING btree ("provider_id");--> statement-breakpoint
118+
CREATE INDEX "credential_account_id_idx" ON "credential" USING btree ("account_id");--> statement-breakpoint
119+
CREATE INDEX "credential_env_owner_user_id_idx" ON "credential" USING btree ("env_owner_user_id");--> statement-breakpoint
120+
CREATE UNIQUE INDEX "credential_workspace_account_unique" ON "credential" USING btree ("workspace_id","account_id") WHERE account_id IS NOT NULL;--> statement-breakpoint
121+
CREATE UNIQUE INDEX "credential_workspace_env_unique" ON "credential" USING btree ("workspace_id","type","env_key") WHERE type = 'env_workspace';--> statement-breakpoint
122+
CREATE UNIQUE INDEX "credential_workspace_personal_env_unique" ON "credential" USING btree ("workspace_id","type","env_key","env_owner_user_id") WHERE type = 'env_personal';--> statement-breakpoint
123+
CREATE INDEX "credential_member_credential_id_idx" ON "credential_member" USING btree ("credential_id");--> statement-breakpoint
124+
CREATE INDEX "credential_member_user_id_idx" ON "credential_member" USING btree ("user_id");--> statement-breakpoint
125+
CREATE INDEX "credential_member_role_idx" ON "credential_member" USING btree ("role");--> statement-breakpoint
126+
CREATE INDEX "credential_member_status_idx" ON "credential_member" USING btree ("status");--> statement-breakpoint
127+
CREATE UNIQUE INDEX "credential_member_unique" ON "credential_member" USING btree ("credential_id","user_id");--> statement-breakpoint
128+
CREATE UNIQUE INDEX "pending_draft_user_provider_ws" ON "pending_credential_draft" USING btree ("user_id","provider_id","workspace_id");
129+
--> statement-breakpoint
130+
-- ============================================================
131+
-- BACKFILL: Create credentials and members from existing data
132+
-- ============================================================
133+
134+
-- Helper CTE: all workspace members (from permissions + workspace owners)
135+
-- Used by all three backfill sections below.
136+
137+
-- ----------------------------------------------------------
138+
-- 1. OAuth credentials
139+
-- ----------------------------------------------------------
140+
-- For each (account, workspace) where account owner has workspace access,
141+
-- create a "Default <Service Name> Credential".
142+
-- Account owner = admin, other workspace members = member.
143+
144+
WITH provider_names(pid, sname) AS (
145+
VALUES
146+
('google-email', 'Gmail'),
147+
('google-drive', 'Google Drive'),
148+
('google-docs', 'Google Docs'),
149+
('google-sheets', 'Google Sheets'),
150+
('google-forms', 'Google Forms'),
151+
('google-calendar', 'Google Calendar'),
152+
('google-vault', 'Google Vault'),
153+
('google-slides', 'Google Slides'),
154+
('google-groups', 'Google Groups'),
155+
('slack', 'Slack'),
156+
('notion', 'Notion'),
157+
('confluence', 'Confluence'),
158+
('jira', 'Jira'),
159+
('jira-service-management', 'Jira Service Management'),
160+
('linear', 'Linear'),
161+
('airtable', 'Airtable'),
162+
('asana', 'Asana'),
163+
('hubspot', 'HubSpot'),
164+
('salesforce', 'Salesforce'),
165+
('pipedrive', 'Pipedrive'),
166+
('microsoft-teams', 'Microsoft Teams'),
167+
('microsoft-planner', 'Microsoft Planner'),
168+
('microsoft-excel', 'Microsoft Excel'),
169+
('outlook', 'Outlook'),
170+
('onedrive', 'OneDrive'),
171+
('sharepoint', 'SharePoint'),
172+
('dropbox', 'Dropbox'),
173+
('wordpress', 'WordPress'),
174+
('webflow', 'Webflow'),
175+
('wealthbox', 'Wealthbox'),
176+
('spotify', 'Spotify'),
177+
('x', 'X'),
178+
('reddit', 'Reddit'),
179+
('linkedin', 'LinkedIn'),
180+
('trello', 'Trello'),
181+
('shopify', 'Shopify'),
182+
('zoom', 'Zoom'),
183+
('calcom', 'Cal.com'),
184+
('discord', 'Discord'),
185+
('box', 'Box'),
186+
('github-repo', 'GitHub'),
187+
('vertex-ai', 'Vertex AI'),
188+
('supabase', 'Supabase')
189+
),
190+
oauth_targets AS (
191+
SELECT
192+
'cred_' || md5(wua.workspace_id || ':' || a.id) AS cred_id,
193+
wua.workspace_id,
194+
a.id AS account_id,
195+
a.user_id AS account_owner_id,
196+
a.provider_id,
197+
COALESCE(u.name, 'User') || '''s ' || COALESCE(pn.sname, a.provider_id) AS display_name
198+
FROM "account" a
199+
INNER JOIN (
200+
SELECT DISTINCT w.id AS workspace_id, p.user_id
201+
FROM "permissions" p
202+
INNER JOIN "workspace" w ON w.id = p.entity_id
203+
WHERE p.entity_type = 'workspace'
204+
UNION
205+
SELECT w.id, w.owner_id FROM "workspace" w
206+
) wua ON wua.user_id = a.user_id
207+
INNER JOIN "user" u ON u.id = a.user_id
208+
LEFT JOIN provider_names pn ON pn.pid = a.provider_id
209+
WHERE a.provider_id NOT IN ('credential', 'github', 'google')
210+
),
211+
oauth_workspace_members AS (
212+
SELECT DISTINCT w.id AS workspace_id, p.user_id
213+
FROM "permissions" p
214+
INNER JOIN "workspace" w ON w.id = p.entity_id
215+
WHERE p.entity_type = 'workspace'
216+
UNION
217+
SELECT w.id, w.owner_id FROM "workspace" w
218+
),
219+
_oauth_insert AS (
220+
INSERT INTO "credential" (
221+
"id", "workspace_id", "type", "display_name", "provider_id", "account_id",
222+
"created_by", "created_at", "updated_at"
223+
)
224+
SELECT cred_id, workspace_id, 'oauth'::"credential_type", display_name,
225+
provider_id, account_id, account_owner_id, now(), now()
226+
FROM oauth_targets
227+
ON CONFLICT DO NOTHING
228+
)
229+
INSERT INTO "credential_member" (
230+
"id", "credential_id", "user_id", "role", "status", "joined_at", "invited_by", "created_at", "updated_at"
231+
)
232+
SELECT
233+
'credm_' || md5(ot.cred_id || ':' || owm.user_id),
234+
ot.cred_id,
235+
owm.user_id,
236+
CASE WHEN ot.account_owner_id = owm.user_id THEN 'admin'::"credential_member_role" ELSE 'member'::"credential_member_role" END,
237+
'active'::"credential_member_status",
238+
now(),
239+
ot.account_owner_id,
240+
now(),
241+
now()
242+
FROM oauth_targets ot
243+
INNER JOIN oauth_workspace_members owm ON owm.workspace_id = ot.workspace_id
244+
ON CONFLICT DO NOTHING;
245+
246+
--> statement-breakpoint
247+
-- ----------------------------------------------------------
248+
-- 2. Workspace environment variable credentials
249+
-- ----------------------------------------------------------
250+
-- For each key in workspace_environment.variables JSON,
251+
-- create a credential. Workspace admins = admin, others = member.
252+
253+
WITH ws_env_keys AS (
254+
SELECT
255+
we.workspace_id,
256+
key AS env_key,
257+
w.owner_id
258+
FROM "workspace_environment" we
259+
INNER JOIN "workspace" w ON w.id = we.workspace_id
260+
CROSS JOIN LATERAL json_object_keys(we.variables::json) AS key
261+
),
262+
ws_env_targets AS (
263+
SELECT
264+
'cred_' || md5(wek.workspace_id || ':env_workspace:' || wek.env_key) AS cred_id,
265+
wek.workspace_id,
266+
wek.env_key,
267+
wek.owner_id
268+
FROM ws_env_keys wek
269+
),
270+
ws_workspace_members AS (
271+
SELECT DISTINCT ON (workspace_id, user_id)
272+
workspace_id, user_id, permission_type
273+
FROM (
274+
SELECT w.id AS workspace_id, p.user_id, p.permission_type
275+
FROM "permissions" p
276+
INNER JOIN "workspace" w ON w.id = p.entity_id
277+
WHERE p.entity_type = 'workspace'
278+
UNION ALL
279+
SELECT w.id, w.owner_id, 'admin'::"permission_type"
280+
FROM "workspace" w
281+
) sub
282+
ORDER BY workspace_id, user_id, (permission_type = 'admin') DESC
283+
),
284+
_ws_env_insert AS (
285+
INSERT INTO "credential" (
286+
"id", "workspace_id", "type", "display_name", "env_key",
287+
"created_by", "created_at", "updated_at"
288+
)
289+
SELECT cred_id, workspace_id, 'env_workspace'::"credential_type",
290+
env_key, env_key, owner_id, now(), now()
291+
FROM ws_env_targets
292+
ON CONFLICT DO NOTHING
293+
)
294+
INSERT INTO "credential_member" (
295+
"id", "credential_id", "user_id", "role", "status", "joined_at", "invited_by", "created_at", "updated_at"
296+
)
297+
SELECT
298+
'credm_' || md5(wet.cred_id || ':' || wm.user_id),
299+
wet.cred_id,
300+
wm.user_id,
301+
CASE WHEN wm.permission_type = 'admin' THEN 'admin'::"credential_member_role" ELSE 'member'::"credential_member_role" END,
302+
'active'::"credential_member_status",
303+
now(),
304+
wet.owner_id,
305+
now(),
306+
now()
307+
FROM ws_env_targets wet
308+
INNER JOIN ws_workspace_members wm ON wm.workspace_id = wet.workspace_id
309+
ON CONFLICT DO NOTHING;
310+
311+
--> statement-breakpoint
312+
-- ----------------------------------------------------------
313+
-- 3. Personal environment variable credentials
314+
-- ----------------------------------------------------------
315+
-- For each key in environment.variables JSON, for each workspace
316+
-- the user belongs to, create a credential with the user as admin.
317+
318+
WITH personal_env_keys AS (
319+
SELECT
320+
e.user_id,
321+
key AS env_key
322+
FROM "environment" e
323+
CROSS JOIN LATERAL json_object_keys(e.variables::json) AS key
324+
),
325+
personal_env_targets AS (
326+
SELECT
327+
'cred_' || md5(wua.workspace_id || ':env_personal:' || pek.env_key || ':' || pek.user_id) AS cred_id,
328+
wua.workspace_id,
329+
pek.env_key,
330+
pek.user_id
331+
FROM personal_env_keys pek
332+
INNER JOIN (
333+
SELECT DISTINCT w.id AS workspace_id, p.user_id
334+
FROM "permissions" p
335+
INNER JOIN "workspace" w ON w.id = p.entity_id
336+
WHERE p.entity_type = 'workspace'
337+
UNION
338+
SELECT w.id, w.owner_id FROM "workspace" w
339+
) wua ON wua.user_id = pek.user_id
340+
),
341+
_personal_env_insert AS (
342+
INSERT INTO "credential" (
343+
"id", "workspace_id", "type", "display_name", "env_key", "env_owner_user_id",
344+
"created_by", "created_at", "updated_at"
345+
)
346+
SELECT cred_id, workspace_id, 'env_personal'::"credential_type",
347+
env_key, env_key, user_id, user_id, now(), now()
348+
FROM personal_env_targets
349+
ON CONFLICT DO NOTHING
350+
)
351+
INSERT INTO "credential_member" (
352+
"id", "credential_id", "user_id", "role", "status", "joined_at", "invited_by", "created_at", "updated_at"
353+
)
354+
SELECT
355+
'credm_' || md5(pet.cred_id || ':' || pet.user_id),
356+
pet.cred_id,
357+
pet.user_id,
358+
'admin'::"credential_member_role",
359+
'active'::"credential_member_status",
360+
now(),
361+
pet.user_id,
362+
now(),
363+
now()
364+
FROM personal_env_targets pet
365+
ON CONFLICT DO NOTHING;

0 commit comments

Comments
 (0)