Change summary
crates/collab/migrations.sqlite/20221109000000_test_schema.sql | 4
crates/collab/migrations/20250702185129_add_cascading_delete_to_repository_entries.sql | 25
crates/collab/src/db/queries/servers.rs | 44
3 files changed, 71 insertions(+), 2 deletions(-)
Detailed changes
@@ -107,7 +107,7 @@ CREATE INDEX "index_worktree_entries_on_project_id" ON "worktree_entries" ("proj
CREATE INDEX "index_worktree_entries_on_project_id_and_worktree_id" ON "worktree_entries" ("project_id", "worktree_id");
CREATE TABLE "project_repositories" (
- "project_id" INTEGER NOT NULL,
+ "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
"abs_path" VARCHAR,
"id" INTEGER NOT NULL,
"entry_ids" VARCHAR,
@@ -124,7 +124,7 @@ CREATE TABLE "project_repositories" (
CREATE INDEX "index_project_repositories_on_project_id" ON "project_repositories" ("project_id");
CREATE TABLE "project_repository_statuses" (
- "project_id" INTEGER NOT NULL,
+ "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
"repository_id" INTEGER NOT NULL,
"repo_path" VARCHAR NOT NULL,
"status" INT8 NOT NULL,
@@ -0,0 +1,25 @@
+DELETE FROM project_repositories
+WHERE project_id NOT IN (SELECT id FROM projects);
+
+ALTER TABLE project_repositories
+ ADD CONSTRAINT fk_project_repositories_project_id
+ FOREIGN KEY (project_id)
+ REFERENCES projects (id)
+ ON DELETE CASCADE
+ NOT VALID;
+
+ALTER TABLE project_repositories
+ VALIDATE CONSTRAINT fk_project_repositories_project_id;
+
+DELETE FROM project_repository_statuses
+WHERE project_id NOT IN (SELECT id FROM projects);
+
+ALTER TABLE project_repository_statuses
+ ADD CONSTRAINT fk_project_repository_statuses_project_id
+ FOREIGN KEY (project_id)
+ REFERENCES projects (id)
+ ON DELETE CASCADE
+ NOT VALID;
+
+ALTER TABLE project_repository_statuses
+ VALIDATE CONSTRAINT fk_project_repository_statuses_project_id;
@@ -142,6 +142,50 @@ impl Database {
}
}
+ loop {
+ let delete_query = Query::delete()
+ .from_table(project_repository_statuses::Entity)
+ .and_where(
+ Expr::tuple([Expr::col((
+ project_repository_statuses::Entity,
+ project_repository_statuses::Column::ProjectId,
+ ))
+ .into()])
+ .in_subquery(
+ Query::select()
+ .columns([(
+ project_repository_statuses::Entity,
+ project_repository_statuses::Column::ProjectId,
+ )])
+ .from(project_repository_statuses::Entity)
+ .inner_join(
+ project::Entity,
+ Expr::col((project::Entity, project::Column::Id)).equals((
+ project_repository_statuses::Entity,
+ project_repository_statuses::Column::ProjectId,
+ )),
+ )
+ .and_where(project::Column::HostConnectionServerId.ne(server_id))
+ .limit(10000)
+ .to_owned(),
+ ),
+ )
+ .to_owned();
+
+ let statement = Statement::from_sql_and_values(
+ tx.get_database_backend(),
+ delete_query
+ .to_string(sea_orm::sea_query::PostgresQueryBuilder)
+ .as_str(),
+ vec![],
+ );
+
+ let result = tx.execute(statement).await?;
+ if result.rows_affected() == 0 {
+ break;
+ }
+ }
+
Ok(())
})
.await