Get DB channels query working with postgres

Max Brunsfeld and Mikayla created

Co-authored-by: Mikayla <mikayla@zed.dev>

Change summary

crates/collab/migrations/20230727150500_add_channels.sql | 21 +
crates/collab/src/db.rs                                  | 76 ---------
crates/collab/src/db/tests.rs                            | 67 ++++++++
3 files changed, 86 insertions(+), 78 deletions(-)

Detailed changes

crates/collab/migrations/20230727150500_add_channels.sql 🔗

@@ -1,19 +1,28 @@
+DROP TABLE "channel_messages";
+DROP TABLE "channel_memberships";
+DROP TABLE "org_memberships";
+DROP TABLE "orgs";
+DROP TABLE "channels";
+
 CREATE TABLE "channels" (
     "id" SERIAL PRIMARY KEY,
-    "id_path" TEXT NOT NULL,
     "name" VARCHAR NOT NULL,
     "room_id" INTEGER REFERENCES rooms (id) ON DELETE SET NULL,
-    "created_at" TIMESTAMP NOT NULL DEFAULT now
-)
+    "created_at" TIMESTAMP NOT NULL DEFAULT now()
+);
 
-CREATE UNIQUE INDEX "index_channels_on_id_path" ON "channels" ("id_path");
+CREATE TABLE "channel_parents" (
+    "child_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
+    "parent_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
+    PRIMARY KEY(child_id, parent_id)
+);
 
 CREATE TABLE "channel_members" (
     "id" SERIAL PRIMARY KEY,
     "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
     "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
     "admin" BOOLEAN NOT NULL DEFAULT false,
-    "updated_at" TIMESTAMP NOT NULL DEFAULT now
-)
+    "updated_at" TIMESTAMP NOT NULL DEFAULT now()
+);
 
 CREATE UNIQUE INDEX "index_channel_members_on_channel_id_and_user_id" ON "channel_members" ("channel_id", "user_id");

crates/collab/src/db.rs 🔗

@@ -39,10 +39,7 @@ use sea_orm::{
     DbErr, FromQueryResult, IntoActiveModel, IsolationLevel, JoinType, QueryOrder, QuerySelect,
     Statement, TransactionTrait,
 };
-use sea_query::{
-    Alias, ColumnRef, CommonTableExpression, Expr, OnConflict, Order, Query, QueryStatementWriter,
-    SelectStatement, UnionType, WithClause,
-};
+use sea_query::{Alias, Expr, OnConflict, Query};
 use serde::{Deserialize, Serialize};
 pub use signup::{Invite, NewSignup, WaitlistSummary};
 use sqlx::migrate::{Migrate, Migration, MigrationSource};
@@ -3086,13 +3083,12 @@ impl Database {
         self.transaction(|tx| async move {
             let tx = tx;
 
-            // This is the SQL statement we want to generate:
             let sql = r#"
             WITH RECURSIVE channel_tree(child_id, parent_id, depth) AS (
-                    SELECT channel_id as child_id, NULL as parent_id, 0
+                    SELECT channel_id as child_id, CAST(NULL as INTEGER) as parent_id, 0
                     FROM channel_members
-                    WHERE user_id = ?
-                UNION ALL
+                    WHERE user_id = $1
+                UNION
                     SELECT channel_parents.child_id, channel_parents.parent_id, channel_tree.depth + 1
                     FROM channel_parents, channel_tree
                     WHERE channel_parents.parent_id = channel_tree.child_id
@@ -3103,70 +3099,6 @@ impl Database {
             ORDER BY channel_tree.depth;
             "#;
 
-            // let root_channel_ids_query = SelectStatement::new()
-            //     .column(channel_member::Column::ChannelId)
-            //     .expr(Expr::value("NULL"))
-            //     .from(channel_member::Entity.table_ref())
-            //     .and_where(
-            //         Expr::col(channel_member::Column::UserId)
-            //             .eq(Expr::cust_with_values("?", vec![user_id])),
-            //     );
-
-            // let build_tree_query = SelectStatement::new()
-            //     .column(channel_parent::Column::ChildId)
-            //     .column(channel_parent::Column::ParentId)
-            //     .expr(Expr::col(Alias::new("channel_tree.depth")).add(1i32))
-            //     .from(Alias::new("channel_tree"))
-            //     .and_where(
-            //         Expr::col(channel_parent::Column::ParentId)
-            //             .equals(Alias::new("channel_tree"), Alias::new("child_id")),
-            //     )
-            //     .to_owned();
-
-            // let common_table_expression = CommonTableExpression::new()
-            //     .query(
-            //         root_channel_ids_query
-            //             .union(UnionType::Distinct, build_tree_query)
-            //             .to_owned(),
-            //     )
-            //     .column(Alias::new("child_id"))
-            //     .column(Alias::new("parent_id"))
-            //     .column(Alias::new("depth"))
-            //     .table_name(Alias::new("channel_tree"))
-            //     .to_owned();
-
-            // let select = SelectStatement::new()
-            //     .expr_as(
-            //         Expr::col(Alias::new("channel_tree.child_id")),
-            //         Alias::new("id"),
-            //     )
-            //     .column(channel::Column::Name)
-            //     .column(Alias::new("channel_tree.parent_id"))
-            //     .from(Alias::new("channel_tree"))
-            //     .inner_join(
-            //         channel::Entity.table_ref(),
-            //         Expr::eq(
-            //             channel::Column::Id.into_expr(),
-            //             Expr::tbl(Alias::new("channel_tree"), Alias::new("child_id")),
-            //         ),
-            //     )
-            //     .order_by(Alias::new("channel_tree.child_id"), Order::Asc)
-            //     .to_owned();
-
-            // let with_clause = WithClause::new()
-            //     .recursive(true)
-            //     .cte(common_table_expression)
-            //     .to_owned();
-
-            // let query = select.with(with_clause);
-
-            // let query = SelectStatement::new()
-            //     .column(ColumnRef::Asterisk)
-            //     .from_subquery(query, Alias::new("channel_tree")
-            //     .to_owned();
-
-            // let stmt = self.pool.get_database_backend().build(&query);
-
             let stmt = Statement::from_sql_and_values(
                 self.pool.get_database_backend(),
                 sql,

crates/collab/src/db/tests.rs 🔗

@@ -879,6 +879,73 @@ async fn test_invite_codes() {
     assert!(db.has_contact(user5, user1).await.unwrap());
 }
 
+test_both_dbs!(test_channels_postgres, test_channels_sqlite, db, {
+    let a_id = db
+        .create_user(
+            "user1@example.com",
+            false,
+            NewUserParams {
+                github_login: "user1".into(),
+                github_user_id: 5,
+                invite_count: 0,
+            },
+        )
+        .await
+        .unwrap()
+        .user_id;
+
+    let zed_id = db.create_root_channel("zed").await.unwrap();
+    let crdb_id = db.create_channel("crdb", Some(zed_id)).await.unwrap();
+    let livestreaming_id = db
+        .create_channel("livestreaming", Some(zed_id))
+        .await
+        .unwrap();
+    let replace_id = db.create_channel("replace", Some(zed_id)).await.unwrap();
+    let rust_id = db.create_root_channel("rust").await.unwrap();
+    let cargo_id = db.create_channel("cargo", Some(rust_id)).await.unwrap();
+
+    db.add_channel_member(zed_id, a_id).await.unwrap();
+    db.add_channel_member(rust_id, a_id).await.unwrap();
+
+    let channels = db.get_channels(a_id).await.unwrap();
+
+    assert_eq!(
+        channels,
+        vec![
+            Channel {
+                id: zed_id,
+                name: "zed".to_string(),
+                parent_id: None,
+            },
+            Channel {
+                id: rust_id,
+                name: "rust".to_string(),
+                parent_id: None,
+            },
+            Channel {
+                id: crdb_id,
+                name: "crdb".to_string(),
+                parent_id: Some(zed_id),
+            },
+            Channel {
+                id: livestreaming_id,
+                name: "livestreaming".to_string(),
+                parent_id: Some(zed_id),
+            },
+            Channel {
+                id: replace_id,
+                name: "replace".to_string(),
+                parent_id: Some(zed_id),
+            },
+            Channel {
+                id: cargo_id,
+                name: "cargo".to_string(),
+                parent_id: Some(rust_id),
+            }
+        ]
+    );
+});
+
 #[gpui::test]
 async fn test_multiple_signup_overwrite() {
     let test_db = TestDb::postgres(build_background_executor());