Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

🗃️ feat: update db schema to add user_id for data export #7022

Merged
merged 10 commits into from
Mar 18, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
16 changes: 16 additions & 0 deletions docs/developer/database-schema.dbml
Original file line number Diff line number Diff line change
Expand Up @@ -122,6 +122,10 @@ table files {
accessed_at "timestamp with time zone" [not null, default: `now()`]
created_at "timestamp with time zone" [not null, default: `now()`]
updated_at "timestamp with time zone" [not null, default: `now()`]

indexes {
file_hash [name: 'file_hash_idx']
}
}

table global_files {
Expand All @@ -130,13 +134,15 @@ table global_files {
size integer [not null]
url text [not null]
metadata jsonb
creator text [not null]
created_at "timestamp with time zone" [not null, default: `now()`]
accessed_at "timestamp with time zone" [not null, default: `now()`]
}

table knowledge_base_files {
knowledge_base_id text [not null]
file_id text [not null]
user_id text [not null]
created_at "timestamp with time zone" [not null, default: `now()`]

indexes {
Expand All @@ -161,6 +167,7 @@ table knowledge_bases {
table message_chunks {
message_id text
chunk_id uuid
user_id text [not null]

indexes {
(chunk_id, message_id) [pk]
Expand All @@ -176,13 +183,15 @@ table message_plugins {
identifier text
state jsonb
error jsonb
user_id text [not null]
}

table message_queries {
id uuid [pk, not null, default: `gen_random_uuid()`]
message_id text [not null]
rewrite_query text
user_query text
user_id text [not null]
embeddings_id uuid
}

Expand All @@ -191,6 +200,7 @@ table message_query_chunks {
query_id uuid
chunk_id uuid
similarity "numeric(6, 5)"
user_id text [not null]

indexes {
(chunk_id, id, query_id) [pk]
Expand All @@ -202,13 +212,15 @@ table message_tts {
content_md5 text
file_id text
voice text
user_id text [not null]
}

table message_translates {
id text [pk, not null]
content text
from text
to text
user_id text [not null]
}

table messages {
Expand Down Expand Up @@ -249,6 +261,7 @@ table messages {
table messages_files {
file_id text [not null]
message_id text [not null]
user_id text [not null]

indexes {
(file_id, message_id) [pk]
Expand Down Expand Up @@ -404,6 +417,7 @@ table rag_eval_evaluation_records {
table agents_to_sessions {
agent_id text [not null]
session_id text [not null]
user_id text [not null]

indexes {
(agent_id, session_id) [pk]
Expand All @@ -414,6 +428,7 @@ table file_chunks {
file_id varchar
chunk_id uuid
created_at "timestamp with time zone" [not null, default: `now()`]
user_id text [not null]

indexes {
(file_id, chunk_id) [pk]
Expand All @@ -423,6 +438,7 @@ table file_chunks {
table files_to_sessions {
file_id text [not null]
session_id text [not null]
user_id text [not null]

indexes {
(file_id, session_id) [pk]
Expand Down
4 changes: 2 additions & 2 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -65,8 +65,8 @@
"test": "npm run test-app && npm run test-server",
"test-app": "vitest run --config vitest.config.ts",
"test-app:coverage": "vitest run --config vitest.config.ts --coverage",
"test-server": "vitest run --config vitest.server.config.ts",
"test-server:coverage": "vitest run --config vitest.server.config.ts --coverage",
"test-server": "TEST_SERVER_DB=1 vitest run --config vitest.server.config.ts",
"test-server:coverage": "TEST_SERVER_DB=1 vitest run --config vitest.server.config.ts --coverage",
"test:update": "vitest -u",
"type-check": "tsc --noEmit",
"webhook:ngrok": "ngrok http http://localhost:3011",
Expand Down
22 changes: 14 additions & 8 deletions src/database/client/db.ts
Original file line number Diff line number Diff line change
Expand Up @@ -146,13 +146,15 @@ export class DatabaseManager {
private async migrate(skipMultiRun = false): Promise<DrizzleInstance> {
if (this.isLocalDBSchemaSynced && skipMultiRun) return this.db;

const cacheHash = localStorage.getItem(pgliteSchemaHashCache);
const hash = Md5.hashStr(JSON.stringify(migrations));

// if hash is the same, no need to migrate
if (hash === cacheHash) {
this.isLocalDBSchemaSynced = true;
return this.db;
let hash: string | undefined;
if (typeof localStorage !== 'undefined') {
const cacheHash = localStorage.getItem(pgliteSchemaHashCache);
hash = Md5.hashStr(JSON.stringify(migrations));
// if hash is the same, no need to migrate
if (hash === cacheHash) {
this.isLocalDBSchemaSynced = true;
return this.db;
}
}

const start = Date.now();
Expand All @@ -162,7 +164,11 @@ export class DatabaseManager {
// refs: https://github.com/drizzle-team/drizzle-orm/discussions/2532
// @ts-expect-error
await this.db.dialect.migrate(migrations, this.db.session, {});
localStorage.setItem(pgliteSchemaHashCache, hash);

if (typeof localStorage !== 'undefined' && hash) {
localStorage.setItem(pgliteSchemaHashCache, hash);
}

this.isLocalDBSchemaSynced = true;

console.info(`🗂 Migration success, take ${Date.now() - start}ms`);
Expand Down
62 changes: 62 additions & 0 deletions src/database/client/migrations.json
Original file line number Diff line number Diff line change
Expand Up @@ -323,5 +323,67 @@
"bps": true,
"folderMillis": 1741844738677,
"hash": "2a7a98be2e49361391444d6fabf3fb5db0bcb6a65e5540e9c3d426ceeb1f7f3a"
},
{
"sql": [
"-- Complete User ID Migration Script\n-- Includes adding columns to all tables, populating data, and setting constraints\n\nBEGIN;",
"\n\nCREATE INDEX \"file_hash_idx\" ON \"files\" USING btree (\"file_hash\");",
"\n\n-- Step 1: Add nullable user_id columns to all required tables\nALTER TABLE \"global_files\" ADD COLUMN IF NOT EXISTS \"creator\" text;",
"\nALTER TABLE \"knowledge_base_files\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"message_chunks\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"message_plugins\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"message_queries\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"message_query_chunks\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"message_tts\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"message_translates\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"messages_files\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"agents_to_sessions\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"file_chunks\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\nALTER TABLE \"files_to_sessions\" ADD COLUMN IF NOT EXISTS \"user_id\" text;",
"\n\n-- Step 2: Populate user_id fields\n-- Retrieve user_id from associated tables\n\n-- Populate user_id for knowledge_base_files\nUPDATE \"knowledge_base_files\" AS kbf\nSET \"user_id\" = kb.\"user_id\"\n FROM \"knowledge_bases\" AS kb\nWHERE kbf.\"knowledge_base_id\" = kb.\"id\";",
"\n\n-- Populate user_id for message_chunks\nUPDATE \"message_chunks\" AS mc\nSET \"user_id\" = m.\"user_id\"\n FROM \"messages\" AS m\nWHERE mc.\"message_id\" = m.\"id\";",
"\n\n-- Populate user_id for message_plugins (directly from messages table)\nUPDATE \"message_plugins\" AS mp\nSET \"user_id\" = m.\"user_id\"\n FROM \"messages\" AS m\nWHERE mp.\"id\" = m.\"id\";",
"\n\n-- Populate user_id for message_queries\nUPDATE \"message_queries\" AS mq\nSET \"user_id\" = m.\"user_id\"\n FROM \"messages\" AS m\nWHERE mq.\"message_id\" = m.\"id\";",
"\n\n-- Populate user_id for message_query_chunks\nUPDATE \"message_query_chunks\" AS mqc\nSET \"user_id\" = mq.\"user_id\"\n FROM \"message_queries\" AS mq\nWHERE mqc.\"query_id\" = mq.\"id\";",
"\n\n-- Populate user_id for message_tts\nUPDATE \"message_tts\" AS mt\nSET \"user_id\" = m.\"user_id\"\n FROM \"messages\" AS m\nWHERE mt.\"id\" = m.\"id\";",
"\n\n-- Populate user_id for message_translates\nUPDATE \"message_translates\" AS mt\nSET \"user_id\" = m.\"user_id\"\n FROM \"messages\" AS m\nWHERE mt.\"id\" = m.\"id\";",
"\n\n-- Populate user_id for messages_files\nUPDATE \"messages_files\" AS mf\nSET \"user_id\" = m.\"user_id\"\n FROM \"messages\" AS m\nWHERE mf.\"message_id\" = m.\"id\";",
"\n\n-- Populate creator for global_files (get the first user who created the file from files table)\nUPDATE \"global_files\" AS gf\nSET \"creator\" = (\n SELECT f.\"user_id\"\n FROM \"files\" AS f\n WHERE f.\"file_hash\" = gf.\"hash_id\"\n ORDER BY f.\"created_at\" ASC\n LIMIT 1\n );",
"\n\n-- Delete global_files records where no user has used the file in the files table\nDELETE FROM \"global_files\"\nWHERE \"creator\" IS NULL;",
"\n\n-- Populate user_id for agents_to_sessions\nUPDATE \"agents_to_sessions\" AS ats\nSET \"user_id\" = a.\"user_id\"\n FROM \"agents\" AS a\nWHERE ats.\"agent_id\" = a.\"id\";",
"\n\n-- Populate user_id for file_chunks\nUPDATE \"file_chunks\" AS fc\nSET \"user_id\" = f.\"user_id\"\n FROM \"files\" AS f\nWHERE fc.\"file_id\" = f.\"id\";",
"\n\n-- Populate user_id for files_to_sessions\nUPDATE \"files_to_sessions\" AS fts\nSET \"user_id\" = f.\"user_id\"\n FROM \"files\" AS f\nWHERE fts.\"file_id\" = f.\"id\";",
"\n\n-- Get user_id from sessions table (handle potential NULL values)\nUPDATE \"files_to_sessions\" AS fts\nSET \"user_id\" = s.\"user_id\"\n FROM \"sessions\" AS s\nWHERE fts.\"session_id\" = s.\"id\" AND fts.\"user_id\" IS NULL;",
"\n\nUPDATE \"agents_to_sessions\" AS ats\nSET \"user_id\" = s.\"user_id\"\n FROM \"sessions\" AS s\nWHERE ats.\"session_id\" = s.\"id\" AND ats.\"user_id\" IS NULL;",
"\n\n-- Step 3: Check for any unpopulated records\nDO $$\nDECLARE\nkb_files_count INTEGER;\n msg_chunks_count INTEGER;\n msg_plugins_count INTEGER;\n msg_queries_count INTEGER;\n msg_query_chunks_count INTEGER;\n msg_tts_count INTEGER;\n msg_translates_count INTEGER;\n msgs_files_count INTEGER;\n agents_sessions_count INTEGER;\n file_chunks_count INTEGER;\n files_sessions_count INTEGER;\nBEGIN\nSELECT COUNT(*) INTO kb_files_count FROM \"knowledge_base_files\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO msg_chunks_count FROM \"message_chunks\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO msg_plugins_count FROM \"message_plugins\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO msg_queries_count FROM \"message_queries\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO msg_query_chunks_count FROM \"message_query_chunks\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO msg_tts_count FROM \"message_tts\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO msg_translates_count FROM \"message_translates\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO msgs_files_count FROM \"messages_files\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO agents_sessions_count FROM \"agents_to_sessions\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO file_chunks_count FROM \"file_chunks\" WHERE \"user_id\" IS NULL;\nSELECT COUNT(*) INTO files_sessions_count FROM \"files_to_sessions\" WHERE \"user_id\" IS NULL;\n\nIF kb_files_count > 0 OR msg_chunks_count > 0 OR msg_plugins_count > 0 OR\n msg_queries_count > 0 OR msg_query_chunks_count > 0 OR msg_tts_count > 0 OR\n msg_translates_count > 0 OR msgs_files_count > 0 OR agents_sessions_count > 0 OR\n file_chunks_count > 0 OR files_sessions_count > 0 THEN\n RAISE EXCEPTION 'There are records with NULL user_id values that could not be populated';\nEND IF;\nEND $$;",
"\n\n-- Step 4: Add NOT NULL constraints and foreign keys\nALTER TABLE \"knowledge_base_files\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"message_chunks\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"message_plugins\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"message_queries\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"message_query_chunks\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"message_tts\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"message_translates\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"messages_files\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"agents_to_sessions\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"file_chunks\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\nALTER TABLE \"files_to_sessions\" ALTER COLUMN \"user_id\" SET NOT NULL;",
"\n\n-- Add foreign key constraints\nALTER TABLE \"global_files\"\n ADD CONSTRAINT \"global_files_creator_users_id_fk\"\n FOREIGN KEY (\"creator\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE SET NULL ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"knowledge_base_files\"\n ADD CONSTRAINT \"knowledge_base_files_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"message_chunks\"\n ADD CONSTRAINT \"message_chunks_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"message_plugins\"\n ADD CONSTRAINT \"message_plugins_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"message_queries\"\n ADD CONSTRAINT \"message_queries_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"message_query_chunks\"\n ADD CONSTRAINT \"message_query_chunks_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"message_tts\"\n ADD CONSTRAINT \"message_tts_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"message_translates\"\n ADD CONSTRAINT \"message_translates_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"messages_files\"\n ADD CONSTRAINT \"messages_files_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"agents_to_sessions\"\n ADD CONSTRAINT \"agents_to_sessions_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"file_chunks\"\n ADD CONSTRAINT \"file_chunks_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nALTER TABLE \"files_to_sessions\"\n ADD CONSTRAINT \"files_to_sessions_user_id_users_id_fk\"\n FOREIGN KEY (\"user_id\") REFERENCES \"public\".\"users\"(\"id\")\n ON DELETE CASCADE ON UPDATE NO ACTION;",
"\n\nCOMMIT;",
"\n"
],
"bps": true,
"folderMillis": 1742269437903,
"hash": "89e91285be422d5f44511c7405f57b57f8dfda4f0304126ae9b0f266e5fd60f1"
}
]
Loading