db.rs

  1use anyhow::Context;
  2use async_std::task::{block_on, yield_now};
  3use serde::Serialize;
  4use sqlx::{types::Uuid, FromRow, Result};
  5use time::OffsetDateTime;
  6
  7pub use async_sqlx_session::PostgresSessionStore as SessionStore;
  8pub use sqlx::postgres::PgPoolOptions as DbOptions;
  9
 10macro_rules! test_support {
 11    ($self:ident, { $($token:tt)* }) => {{
 12        let body = async {
 13            $($token)*
 14        };
 15        if $self.test_mode {
 16            yield_now().await;
 17            block_on(body)
 18        } else {
 19            body.await
 20        }
 21    }};
 22}
 23
 24#[derive(Clone)]
 25pub struct Db {
 26    pool: sqlx::PgPool,
 27    test_mode: bool,
 28}
 29
 30impl Db {
 31    pub async fn new(url: &str, max_connections: u32) -> tide::Result<Self> {
 32        let pool = DbOptions::new()
 33            .max_connections(max_connections)
 34            .connect(url)
 35            .await
 36            .context("failed to connect to postgres database")?;
 37        Ok(Self {
 38            pool,
 39            test_mode: false,
 40        })
 41    }
 42
 43    // signups
 44
 45    pub async fn create_signup(
 46        &self,
 47        github_login: &str,
 48        email_address: &str,
 49        about: &str,
 50        wants_releases: bool,
 51        wants_updates: bool,
 52        wants_community: bool,
 53    ) -> Result<SignupId> {
 54        test_support!(self, {
 55            let query = "
 56                INSERT INTO signups (
 57                    github_login,
 58                    email_address,
 59                    about,
 60                    wants_releases,
 61                    wants_updates,
 62                    wants_community
 63                )
 64                VALUES ($1, $2, $3, $4, $5, $6)
 65                RETURNING id
 66            ";
 67            sqlx::query_scalar(query)
 68                .bind(github_login)
 69                .bind(email_address)
 70                .bind(about)
 71                .bind(wants_releases)
 72                .bind(wants_updates)
 73                .bind(wants_community)
 74                .fetch_one(&self.pool)
 75                .await
 76                .map(SignupId)
 77        })
 78    }
 79
 80    pub async fn get_all_signups(&self) -> Result<Vec<Signup>> {
 81        test_support!(self, {
 82            let query = "SELECT * FROM signups ORDER BY github_login ASC";
 83            sqlx::query_as(query).fetch_all(&self.pool).await
 84        })
 85    }
 86
 87    pub async fn destroy_signup(&self, id: SignupId) -> Result<()> {
 88        test_support!(self, {
 89            let query = "DELETE FROM signups WHERE id = $1";
 90            sqlx::query(query)
 91                .bind(id.0)
 92                .execute(&self.pool)
 93                .await
 94                .map(drop)
 95        })
 96    }
 97
 98    // users
 99
100    pub async fn create_user(&self, github_login: &str, admin: bool) -> Result<UserId> {
101        test_support!(self, {
102            let query = "
103                INSERT INTO users (github_login, admin)
104                VALUES ($1, $2)
105                ON CONFLICT (github_login) DO UPDATE SET github_login = excluded.github_login
106                RETURNING id
107            ";
108            sqlx::query_scalar(query)
109                .bind(github_login)
110                .bind(admin)
111                .fetch_one(&self.pool)
112                .await
113                .map(UserId)
114        })
115    }
116
117    pub async fn get_all_users(&self) -> Result<Vec<User>> {
118        test_support!(self, {
119            let query = "SELECT * FROM users ORDER BY github_login ASC";
120            sqlx::query_as(query).fetch_all(&self.pool).await
121        })
122    }
123
124    pub async fn get_user_by_id(&self, id: UserId) -> Result<Option<User>> {
125        let users = self.get_users_by_ids([id]).await?;
126        Ok(users.into_iter().next())
127    }
128
129    pub async fn get_users_by_ids(
130        &self,
131        ids: impl IntoIterator<Item = UserId>,
132    ) -> Result<Vec<User>> {
133        let ids = ids.into_iter().map(|id| id.0).collect::<Vec<_>>();
134        test_support!(self, {
135            let query = "
136                SELECT users.*
137                FROM users
138                WHERE users.id = ANY ($1)
139            ";
140
141            sqlx::query_as(query).bind(&ids).fetch_all(&self.pool).await
142        })
143    }
144
145    pub async fn get_user_by_github_login(&self, github_login: &str) -> Result<Option<User>> {
146        test_support!(self, {
147            let query = "SELECT * FROM users WHERE github_login = $1 LIMIT 1";
148            sqlx::query_as(query)
149                .bind(github_login)
150                .fetch_optional(&self.pool)
151                .await
152        })
153    }
154
155    pub async fn set_user_is_admin(&self, id: UserId, is_admin: bool) -> Result<()> {
156        test_support!(self, {
157            let query = "UPDATE users SET admin = $1 WHERE id = $2";
158            sqlx::query(query)
159                .bind(is_admin)
160                .bind(id.0)
161                .execute(&self.pool)
162                .await
163                .map(drop)
164        })
165    }
166
167    pub async fn destroy_user(&self, id: UserId) -> Result<()> {
168        test_support!(self, {
169            let query = "DELETE FROM access_tokens WHERE user_id = $1;";
170            sqlx::query(query)
171                .bind(id.0)
172                .execute(&self.pool)
173                .await
174                .map(drop)?;
175            let query = "DELETE FROM users WHERE id = $1;";
176            sqlx::query(query)
177                .bind(id.0)
178                .execute(&self.pool)
179                .await
180                .map(drop)
181        })
182    }
183
184    // access tokens
185
186    pub async fn create_access_token_hash(
187        &self,
188        user_id: UserId,
189        access_token_hash: &str,
190        max_access_token_count: usize,
191    ) -> Result<()> {
192        test_support!(self, {
193            let insert_query = "
194                INSERT INTO access_tokens (user_id, hash)
195                VALUES ($1, $2);
196            ";
197            let cleanup_query = "
198                DELETE FROM access_tokens
199                WHERE id IN (
200                    SELECT id from access_tokens
201                    WHERE user_id = $1
202                    ORDER BY id DESC
203                    OFFSET $3
204                )
205            ";
206
207            let mut tx = self.pool.begin().await?;
208            sqlx::query(insert_query)
209                .bind(user_id.0)
210                .bind(access_token_hash)
211                .execute(&mut tx)
212                .await?;
213            sqlx::query(cleanup_query)
214                .bind(user_id.0)
215                .bind(access_token_hash)
216                .bind(max_access_token_count as u32)
217                .execute(&mut tx)
218                .await?;
219            tx.commit().await
220        })
221    }
222
223    pub async fn get_access_token_hashes(&self, user_id: UserId) -> Result<Vec<String>> {
224        test_support!(self, {
225            let query = "
226                SELECT hash
227                FROM access_tokens
228                WHERE user_id = $1
229                ORDER BY id DESC
230            ";
231            sqlx::query_scalar(query)
232                .bind(user_id.0)
233                .fetch_all(&self.pool)
234                .await
235        })
236    }
237
238    // orgs
239
240    #[allow(unused)] // Help rust-analyzer
241    #[cfg(any(test, feature = "seed-support"))]
242    pub async fn find_org_by_slug(&self, slug: &str) -> Result<Option<Org>> {
243        test_support!(self, {
244            let query = "
245                SELECT *
246                FROM orgs
247                WHERE slug = $1
248            ";
249            sqlx::query_as(query)
250                .bind(slug)
251                .fetch_optional(&self.pool)
252                .await
253        })
254    }
255
256    #[cfg(any(test, feature = "seed-support"))]
257    pub async fn create_org(&self, name: &str, slug: &str) -> Result<OrgId> {
258        test_support!(self, {
259            let query = "
260                INSERT INTO orgs (name, slug)
261                VALUES ($1, $2)
262                RETURNING id
263            ";
264            sqlx::query_scalar(query)
265                .bind(name)
266                .bind(slug)
267                .fetch_one(&self.pool)
268                .await
269                .map(OrgId)
270        })
271    }
272
273    #[cfg(any(test, feature = "seed-support"))]
274    pub async fn add_org_member(
275        &self,
276        org_id: OrgId,
277        user_id: UserId,
278        is_admin: bool,
279    ) -> Result<()> {
280        test_support!(self, {
281            let query = "
282                INSERT INTO org_memberships (org_id, user_id, admin)
283                VALUES ($1, $2, $3)
284                ON CONFLICT DO NOTHING
285            ";
286            sqlx::query(query)
287                .bind(org_id.0)
288                .bind(user_id.0)
289                .bind(is_admin)
290                .execute(&self.pool)
291                .await
292                .map(drop)
293        })
294    }
295
296    // channels
297
298    #[cfg(any(test, feature = "seed-support"))]
299    pub async fn create_org_channel(&self, org_id: OrgId, name: &str) -> Result<ChannelId> {
300        test_support!(self, {
301            let query = "
302                INSERT INTO channels (owner_id, owner_is_user, name)
303                VALUES ($1, false, $2)
304                RETURNING id
305            ";
306            sqlx::query_scalar(query)
307                .bind(org_id.0)
308                .bind(name)
309                .fetch_one(&self.pool)
310                .await
311                .map(ChannelId)
312        })
313    }
314
315    #[allow(unused)] // Help rust-analyzer
316    #[cfg(any(test, feature = "seed-support"))]
317    pub async fn get_org_channels(&self, org_id: OrgId) -> Result<Vec<Channel>> {
318        test_support!(self, {
319            let query = "
320                SELECT *
321                FROM channels
322                WHERE
323                    channels.owner_is_user = false AND
324                    channels.owner_id = $1
325            ";
326            sqlx::query_as(query)
327                .bind(org_id.0)
328                .fetch_all(&self.pool)
329                .await
330        })
331    }
332
333    pub async fn get_accessible_channels(&self, user_id: UserId) -> Result<Vec<Channel>> {
334        test_support!(self, {
335            let query = "
336                SELECT
337                    channels.id, channels.name
338                FROM
339                    channel_memberships, channels
340                WHERE
341                    channel_memberships.user_id = $1 AND
342                    channel_memberships.channel_id = channels.id
343            ";
344            sqlx::query_as(query)
345                .bind(user_id.0)
346                .fetch_all(&self.pool)
347                .await
348        })
349    }
350
351    pub async fn can_user_access_channel(
352        &self,
353        user_id: UserId,
354        channel_id: ChannelId,
355    ) -> Result<bool> {
356        test_support!(self, {
357            let query = "
358                SELECT id
359                FROM channel_memberships
360                WHERE user_id = $1 AND channel_id = $2
361                LIMIT 1
362            ";
363            sqlx::query_scalar::<_, i32>(query)
364                .bind(user_id.0)
365                .bind(channel_id.0)
366                .fetch_optional(&self.pool)
367                .await
368                .map(|e| e.is_some())
369        })
370    }
371
372    #[cfg(any(test, feature = "seed-support"))]
373    pub async fn add_channel_member(
374        &self,
375        channel_id: ChannelId,
376        user_id: UserId,
377        is_admin: bool,
378    ) -> Result<()> {
379        test_support!(self, {
380            let query = "
381                INSERT INTO channel_memberships (channel_id, user_id, admin)
382                VALUES ($1, $2, $3)
383                ON CONFLICT DO NOTHING
384            ";
385            sqlx::query(query)
386                .bind(channel_id.0)
387                .bind(user_id.0)
388                .bind(is_admin)
389                .execute(&self.pool)
390                .await
391                .map(drop)
392        })
393    }
394
395    // messages
396
397    pub async fn create_channel_message(
398        &self,
399        channel_id: ChannelId,
400        sender_id: UserId,
401        body: &str,
402        timestamp: OffsetDateTime,
403        nonce: u128,
404    ) -> Result<MessageId> {
405        test_support!(self, {
406            let query = "
407                INSERT INTO channel_messages (channel_id, sender_id, body, sent_at, nonce)
408                VALUES ($1, $2, $3, $4, $5)
409                ON CONFLICT (nonce) DO UPDATE SET nonce = excluded.nonce
410                RETURNING id
411            ";
412            sqlx::query_scalar(query)
413                .bind(channel_id.0)
414                .bind(sender_id.0)
415                .bind(body)
416                .bind(timestamp)
417                .bind(Uuid::from_u128(nonce))
418                .fetch_one(&self.pool)
419                .await
420                .map(MessageId)
421        })
422    }
423
424    pub async fn get_channel_messages(
425        &self,
426        channel_id: ChannelId,
427        count: usize,
428        before_id: Option<MessageId>,
429    ) -> Result<Vec<ChannelMessage>> {
430        test_support!(self, {
431            let query = r#"
432                SELECT * FROM (
433                    SELECT
434                        id, sender_id, body, sent_at AT TIME ZONE 'UTC' as sent_at, nonce
435                    FROM
436                        channel_messages
437                    WHERE
438                        channel_id = $1 AND
439                        id < $2
440                    ORDER BY id DESC
441                    LIMIT $3
442                ) as recent_messages
443                ORDER BY id ASC
444            "#;
445            sqlx::query_as(query)
446                .bind(channel_id.0)
447                .bind(before_id.unwrap_or(MessageId::MAX))
448                .bind(count as i64)
449                .fetch_all(&self.pool)
450                .await
451        })
452    }
453}
454
455macro_rules! id_type {
456    ($name:ident) => {
457        #[derive(
458            Clone, Copy, Debug, PartialEq, Eq, PartialOrd, Ord, Hash, sqlx::Type, Serialize,
459        )]
460        #[sqlx(transparent)]
461        #[serde(transparent)]
462        pub struct $name(pub i32);
463
464        impl $name {
465            #[allow(unused)]
466            pub const MAX: Self = Self(i32::MAX);
467
468            #[allow(unused)]
469            pub fn from_proto(value: u64) -> Self {
470                Self(value as i32)
471            }
472
473            #[allow(unused)]
474            pub fn to_proto(&self) -> u64 {
475                self.0 as u64
476            }
477        }
478    };
479}
480
481id_type!(UserId);
482#[derive(Debug, FromRow, Serialize, PartialEq)]
483pub struct User {
484    pub id: UserId,
485    pub github_login: String,
486    pub admin: bool,
487}
488
489id_type!(OrgId);
490#[derive(FromRow)]
491pub struct Org {
492    pub id: OrgId,
493    pub name: String,
494    pub slug: String,
495}
496
497id_type!(SignupId);
498#[derive(Debug, FromRow, Serialize)]
499pub struct Signup {
500    pub id: SignupId,
501    pub github_login: String,
502    pub email_address: String,
503    pub about: String,
504    pub wants_releases: Option<bool>,
505    pub wants_updates: Option<bool>,
506    pub wants_community: Option<bool>,
507}
508
509id_type!(ChannelId);
510#[derive(Debug, FromRow, Serialize)]
511pub struct Channel {
512    pub id: ChannelId,
513    pub name: String,
514}
515
516id_type!(MessageId);
517#[derive(Debug, FromRow)]
518pub struct ChannelMessage {
519    pub id: MessageId,
520    pub sender_id: UserId,
521    pub body: String,
522    pub sent_at: OffsetDateTime,
523    pub nonce: Uuid,
524}
525
526#[cfg(test)]
527pub mod tests {
528    use super::*;
529    use rand::prelude::*;
530    use sqlx::{
531        migrate::{MigrateDatabase, Migrator},
532        Postgres,
533    };
534    use std::path::Path;
535
536    pub struct TestDb {
537        pub db: Db,
538        pub name: String,
539        pub url: String,
540    }
541
542    impl TestDb {
543        pub fn new() -> Self {
544            // Enable tests to run in parallel by serializing the creation of each test database.
545            lazy_static::lazy_static! {
546                static ref DB_CREATION: std::sync::Mutex<()> = std::sync::Mutex::new(());
547            }
548
549            let mut rng = StdRng::from_entropy();
550            let name = format!("zed-test-{}", rng.gen::<u128>());
551            let url = format!("postgres://postgres@localhost/{}", name);
552            let migrations_path = Path::new(concat!(env!("CARGO_MANIFEST_DIR"), "/migrations"));
553            let db = block_on(async {
554                {
555                    let _lock = DB_CREATION.lock();
556                    Postgres::create_database(&url)
557                        .await
558                        .expect("failed to create test db");
559                }
560                let mut db = Db::new(&url, 5).await.unwrap();
561                db.test_mode = true;
562                let migrator = Migrator::new(migrations_path).await.unwrap();
563                migrator.run(&db.pool).await.unwrap();
564                db
565            });
566
567            Self { db, name, url }
568        }
569
570        pub fn db(&self) -> &Db {
571            &self.db
572        }
573    }
574
575    impl Drop for TestDb {
576        fn drop(&mut self) {
577            block_on(async {
578                let query = "
579                    SELECT pg_terminate_backend(pg_stat_activity.pid)
580                    FROM pg_stat_activity
581                    WHERE pg_stat_activity.datname = '{}' AND pid <> pg_backend_pid();
582                ";
583                sqlx::query(query)
584                    .bind(&self.name)
585                    .execute(&self.db.pool)
586                    .await
587                    .unwrap();
588                self.db.pool.close().await;
589                Postgres::drop_database(&self.url).await.unwrap();
590            });
591        }
592    }
593
594    #[gpui::test]
595    async fn test_get_users_by_ids() {
596        let test_db = TestDb::new();
597        let db = test_db.db();
598
599        let user = db.create_user("user", false).await.unwrap();
600        let friend1 = db.create_user("friend-1", false).await.unwrap();
601        let friend2 = db.create_user("friend-2", false).await.unwrap();
602        let friend3 = db.create_user("friend-3", false).await.unwrap();
603
604        assert_eq!(
605            db.get_users_by_ids([user, friend1, friend2, friend3])
606                .await
607                .unwrap(),
608            vec![
609                User {
610                    id: user,
611                    github_login: "user".to_string(),
612                    admin: false,
613                },
614                User {
615                    id: friend1,
616                    github_login: "friend-1".to_string(),
617                    admin: false,
618                },
619                User {
620                    id: friend2,
621                    github_login: "friend-2".to_string(),
622                    admin: false,
623                },
624                User {
625                    id: friend3,
626                    github_login: "friend-3".to_string(),
627                    admin: false,
628                }
629            ]
630        );
631    }
632
633    #[gpui::test]
634    async fn test_recent_channel_messages() {
635        let test_db = TestDb::new();
636        let db = test_db.db();
637        let user = db.create_user("user", false).await.unwrap();
638        let org = db.create_org("org", "org").await.unwrap();
639        let channel = db.create_org_channel(org, "channel").await.unwrap();
640        for i in 0..10 {
641            db.create_channel_message(channel, user, &i.to_string(), OffsetDateTime::now_utc(), i)
642                .await
643                .unwrap();
644        }
645
646        let messages = db.get_channel_messages(channel, 5, None).await.unwrap();
647        assert_eq!(
648            messages.iter().map(|m| &m.body).collect::<Vec<_>>(),
649            ["5", "6", "7", "8", "9"]
650        );
651
652        let prev_messages = db
653            .get_channel_messages(channel, 4, Some(messages[0].id))
654            .await
655            .unwrap();
656        assert_eq!(
657            prev_messages.iter().map(|m| &m.body).collect::<Vec<_>>(),
658            ["1", "2", "3", "4"]
659        );
660    }
661
662    #[gpui::test]
663    async fn test_channel_message_nonces() {
664        let test_db = TestDb::new();
665        let db = test_db.db();
666        let user = db.create_user("user", false).await.unwrap();
667        let org = db.create_org("org", "org").await.unwrap();
668        let channel = db.create_org_channel(org, "channel").await.unwrap();
669
670        let msg1_id = db
671            .create_channel_message(channel, user, "1", OffsetDateTime::now_utc(), 1)
672            .await
673            .unwrap();
674        let msg2_id = db
675            .create_channel_message(channel, user, "2", OffsetDateTime::now_utc(), 2)
676            .await
677            .unwrap();
678        let msg3_id = db
679            .create_channel_message(channel, user, "3", OffsetDateTime::now_utc(), 1)
680            .await
681            .unwrap();
682        let msg4_id = db
683            .create_channel_message(channel, user, "4", OffsetDateTime::now_utc(), 2)
684            .await
685            .unwrap();
686
687        assert_ne!(msg1_id, msg2_id);
688        assert_eq!(msg1_id, msg3_id);
689        assert_eq!(msg2_id, msg4_id);
690    }
691
692    #[gpui::test]
693    async fn test_create_access_tokens() {
694        let test_db = TestDb::new();
695        let db = test_db.db();
696        let user = db.create_user("the-user", false).await.unwrap();
697
698        db.create_access_token_hash(user, "h1", 3).await.unwrap();
699        db.create_access_token_hash(user, "h2", 3).await.unwrap();
700        assert_eq!(
701            db.get_access_token_hashes(user).await.unwrap(),
702            &["h2".to_string(), "h1".to_string()]
703        );
704
705        db.create_access_token_hash(user, "h3", 3).await.unwrap();
706        assert_eq!(
707            db.get_access_token_hashes(user).await.unwrap(),
708            &["h3".to_string(), "h2".to_string(), "h1".to_string(),]
709        );
710
711        db.create_access_token_hash(user, "h4", 3).await.unwrap();
712        assert_eq!(
713            db.get_access_token_hashes(user).await.unwrap(),
714            &["h4".to_string(), "h3".to_string(), "h2".to_string(),]
715        );
716
717        db.create_access_token_hash(user, "h5", 3).await.unwrap();
718        assert_eq!(
719            db.get_access_token_hashes(user).await.unwrap(),
720            &["h5".to_string(), "h4".to_string(), "h3".to_string()]
721        );
722    }
723}