1use crate::{Error, Result};
2use anyhow::{anyhow, Context};
3use async_trait::async_trait;
4use axum::http::StatusCode;
5use collections::HashMap;
6use futures::StreamExt;
7use serde::{Deserialize, Serialize};
8pub use sqlx::postgres::PgPoolOptions as DbOptions;
9use sqlx::{types::Uuid, FromRow, QueryBuilder};
10use std::{cmp, ops::Range, time::Duration};
11use time::{OffsetDateTime, PrimitiveDateTime};
12
13#[async_trait]
14pub trait Db: Send + Sync {
15 async fn create_user(
16 &self,
17 email_address: &str,
18 admin: bool,
19 params: NewUserParams,
20 ) -> Result<NewUserResult>;
21 async fn get_all_users(&self, page: u32, limit: u32) -> Result<Vec<User>>;
22 async fn fuzzy_search_users(&self, query: &str, limit: u32) -> Result<Vec<User>>;
23 async fn get_user_by_id(&self, id: UserId) -> Result<Option<User>>;
24 async fn get_user_metrics_id(&self, id: UserId) -> Result<String>;
25 async fn get_users_by_ids(&self, ids: Vec<UserId>) -> Result<Vec<User>>;
26 async fn get_users_with_no_invites(&self, invited_by_another_user: bool) -> Result<Vec<User>>;
27 async fn get_user_by_github_account(
28 &self,
29 github_login: &str,
30 github_user_id: Option<i32>,
31 ) -> Result<Option<User>>;
32 async fn set_user_is_admin(&self, id: UserId, is_admin: bool) -> Result<()>;
33 async fn set_user_connected_once(&self, id: UserId, connected_once: bool) -> Result<()>;
34 async fn destroy_user(&self, id: UserId) -> Result<()>;
35
36 async fn set_invite_count_for_user(&self, id: UserId, count: u32) -> Result<()>;
37 async fn get_invite_code_for_user(&self, id: UserId) -> Result<Option<(String, u32)>>;
38 async fn get_user_for_invite_code(&self, code: &str) -> Result<User>;
39 async fn create_invite_from_code(
40 &self,
41 code: &str,
42 email_address: &str,
43 device_id: Option<&str>,
44 ) -> Result<Invite>;
45
46 async fn create_signup(&self, signup: Signup) -> Result<()>;
47 async fn get_waitlist_summary(&self) -> Result<WaitlistSummary>;
48 async fn get_unsent_invites(&self, count: usize) -> Result<Vec<Invite>>;
49 async fn record_sent_invites(&self, invites: &[Invite]) -> Result<()>;
50 async fn create_user_from_invite(
51 &self,
52 invite: &Invite,
53 user: NewUserParams,
54 ) -> Result<NewUserResult>;
55
56 /// Registers a new project for the given user.
57 async fn register_project(&self, host_user_id: UserId) -> Result<ProjectId>;
58
59 /// Unregisters a project for the given project id.
60 async fn unregister_project(&self, project_id: ProjectId) -> Result<()>;
61
62 /// Update file counts by extension for the given project and worktree.
63 async fn update_worktree_extensions(
64 &self,
65 project_id: ProjectId,
66 worktree_id: u64,
67 extensions: HashMap<String, u32>,
68 ) -> Result<()>;
69
70 /// Get the file counts on the given project keyed by their worktree and extension.
71 async fn get_project_extensions(
72 &self,
73 project_id: ProjectId,
74 ) -> Result<HashMap<u64, HashMap<String, usize>>>;
75
76 /// Record which users have been active in which projects during
77 /// a given period of time.
78 async fn record_user_activity(
79 &self,
80 time_period: Range<OffsetDateTime>,
81 active_projects: &[(UserId, ProjectId)],
82 ) -> Result<()>;
83
84 /// Get the number of users who have been active in the given
85 /// time period for at least the given time duration.
86 async fn get_active_user_count(
87 &self,
88 time_period: Range<OffsetDateTime>,
89 min_duration: Duration,
90 only_collaborative: bool,
91 ) -> Result<usize>;
92
93 /// Get the users that have been most active during the given time period,
94 /// along with the amount of time they have been active in each project.
95 async fn get_top_users_activity_summary(
96 &self,
97 time_period: Range<OffsetDateTime>,
98 max_user_count: usize,
99 ) -> Result<Vec<UserActivitySummary>>;
100
101 /// Get the project activity for the given user and time period.
102 async fn get_user_activity_timeline(
103 &self,
104 time_period: Range<OffsetDateTime>,
105 user_id: UserId,
106 ) -> Result<Vec<UserActivityPeriod>>;
107
108 async fn get_contacts(&self, id: UserId) -> Result<Vec<Contact>>;
109 async fn has_contact(&self, user_id_a: UserId, user_id_b: UserId) -> Result<bool>;
110 async fn send_contact_request(&self, requester_id: UserId, responder_id: UserId) -> Result<()>;
111 async fn remove_contact(&self, requester_id: UserId, responder_id: UserId) -> Result<()>;
112 async fn dismiss_contact_notification(
113 &self,
114 responder_id: UserId,
115 requester_id: UserId,
116 ) -> Result<()>;
117 async fn respond_to_contact_request(
118 &self,
119 responder_id: UserId,
120 requester_id: UserId,
121 accept: bool,
122 ) -> Result<()>;
123
124 async fn create_access_token_hash(
125 &self,
126 user_id: UserId,
127 access_token_hash: &str,
128 max_access_token_count: usize,
129 ) -> Result<()>;
130 async fn get_access_token_hashes(&self, user_id: UserId) -> Result<Vec<String>>;
131
132 #[cfg(any(test, feature = "seed-support"))]
133 async fn find_org_by_slug(&self, slug: &str) -> Result<Option<Org>>;
134 #[cfg(any(test, feature = "seed-support"))]
135 async fn create_org(&self, name: &str, slug: &str) -> Result<OrgId>;
136 #[cfg(any(test, feature = "seed-support"))]
137 async fn add_org_member(&self, org_id: OrgId, user_id: UserId, is_admin: bool) -> Result<()>;
138 #[cfg(any(test, feature = "seed-support"))]
139 async fn create_org_channel(&self, org_id: OrgId, name: &str) -> Result<ChannelId>;
140 #[cfg(any(test, feature = "seed-support"))]
141
142 async fn get_org_channels(&self, org_id: OrgId) -> Result<Vec<Channel>>;
143 async fn get_accessible_channels(&self, user_id: UserId) -> Result<Vec<Channel>>;
144 async fn can_user_access_channel(&self, user_id: UserId, channel_id: ChannelId)
145 -> Result<bool>;
146
147 #[cfg(any(test, feature = "seed-support"))]
148 async fn add_channel_member(
149 &self,
150 channel_id: ChannelId,
151 user_id: UserId,
152 is_admin: bool,
153 ) -> Result<()>;
154 async fn create_channel_message(
155 &self,
156 channel_id: ChannelId,
157 sender_id: UserId,
158 body: &str,
159 timestamp: OffsetDateTime,
160 nonce: u128,
161 ) -> Result<MessageId>;
162 async fn get_channel_messages(
163 &self,
164 channel_id: ChannelId,
165 count: usize,
166 before_id: Option<MessageId>,
167 ) -> Result<Vec<ChannelMessage>>;
168
169 #[cfg(test)]
170 async fn teardown(&self, url: &str);
171
172 #[cfg(test)]
173 fn as_fake(&self) -> Option<&FakeDb>;
174}
175
176pub struct PostgresDb {
177 pool: sqlx::PgPool,
178}
179
180impl PostgresDb {
181 pub async fn new(url: &str, max_connections: u32) -> Result<Self> {
182 let pool = DbOptions::new()
183 .max_connections(max_connections)
184 .connect(url)
185 .await
186 .context("failed to connect to postgres database")?;
187 Ok(Self { pool })
188 }
189
190 pub fn fuzzy_like_string(string: &str) -> String {
191 let mut result = String::with_capacity(string.len() * 2 + 1);
192 for c in string.chars() {
193 if c.is_alphanumeric() {
194 result.push('%');
195 result.push(c);
196 }
197 }
198 result.push('%');
199 result
200 }
201}
202
203#[async_trait]
204impl Db for PostgresDb {
205 // users
206
207 async fn create_user(
208 &self,
209 email_address: &str,
210 admin: bool,
211 params: NewUserParams,
212 ) -> Result<NewUserResult> {
213 let query = "
214 INSERT INTO users (email_address, github_login, github_user_id, admin)
215 VALUES ($1, $2, $3, $4)
216 ON CONFLICT (github_login) DO UPDATE SET github_login = excluded.github_login
217 RETURNING id, metrics_id::text
218 ";
219 let (user_id, metrics_id): (UserId, String) = sqlx::query_as(query)
220 .bind(email_address)
221 .bind(params.github_login)
222 .bind(params.github_user_id)
223 .bind(admin)
224 .fetch_one(&self.pool)
225 .await?;
226 Ok(NewUserResult {
227 user_id,
228 metrics_id,
229 signup_device_id: None,
230 inviting_user_id: None,
231 })
232 }
233
234 async fn get_all_users(&self, page: u32, limit: u32) -> Result<Vec<User>> {
235 let query = "SELECT * FROM users ORDER BY github_login ASC LIMIT $1 OFFSET $2";
236 Ok(sqlx::query_as(query)
237 .bind(limit as i32)
238 .bind((page * limit) as i32)
239 .fetch_all(&self.pool)
240 .await?)
241 }
242
243 async fn fuzzy_search_users(&self, name_query: &str, limit: u32) -> Result<Vec<User>> {
244 let like_string = Self::fuzzy_like_string(name_query);
245 let query = "
246 SELECT users.*
247 FROM users
248 WHERE github_login ILIKE $1
249 ORDER BY github_login <-> $2
250 LIMIT $3
251 ";
252 Ok(sqlx::query_as(query)
253 .bind(like_string)
254 .bind(name_query)
255 .bind(limit as i32)
256 .fetch_all(&self.pool)
257 .await?)
258 }
259
260 async fn get_user_by_id(&self, id: UserId) -> Result<Option<User>> {
261 let users = self.get_users_by_ids(vec![id]).await?;
262 Ok(users.into_iter().next())
263 }
264
265 async fn get_user_metrics_id(&self, id: UserId) -> Result<String> {
266 let query = "
267 SELECT metrics_id::text
268 FROM users
269 WHERE id = $1
270 ";
271 Ok(sqlx::query_scalar(query)
272 .bind(id)
273 .fetch_one(&self.pool)
274 .await?)
275 }
276
277 async fn get_users_by_ids(&self, ids: Vec<UserId>) -> Result<Vec<User>> {
278 let ids = ids.into_iter().map(|id| id.0).collect::<Vec<_>>();
279 let query = "
280 SELECT users.*
281 FROM users
282 WHERE users.id = ANY ($1)
283 ";
284 Ok(sqlx::query_as(query)
285 .bind(&ids)
286 .fetch_all(&self.pool)
287 .await?)
288 }
289
290 async fn get_users_with_no_invites(&self, invited_by_another_user: bool) -> Result<Vec<User>> {
291 let query = format!(
292 "
293 SELECT users.*
294 FROM users
295 WHERE invite_count = 0
296 AND inviter_id IS{} NULL
297 ",
298 if invited_by_another_user { " NOT" } else { "" }
299 );
300
301 Ok(sqlx::query_as(&query).fetch_all(&self.pool).await?)
302 }
303
304 async fn get_user_by_github_account(
305 &self,
306 github_login: &str,
307 github_user_id: Option<i32>,
308 ) -> Result<Option<User>> {
309 if let Some(github_user_id) = github_user_id {
310 let mut user = sqlx::query_as::<_, User>(
311 "
312 UPDATE users
313 SET github_login = $1
314 WHERE github_user_id = $2
315 RETURNING *
316 ",
317 )
318 .bind(github_login)
319 .bind(github_user_id)
320 .fetch_optional(&self.pool)
321 .await?;
322
323 if user.is_none() {
324 user = sqlx::query_as::<_, User>(
325 "
326 UPDATE users
327 SET github_user_id = $1
328 WHERE github_login = $2
329 RETURNING *
330 ",
331 )
332 .bind(github_user_id)
333 .bind(github_login)
334 .fetch_optional(&self.pool)
335 .await?;
336 }
337
338 Ok(user)
339 } else {
340 Ok(sqlx::query_as(
341 "
342 SELECT * FROM users
343 WHERE github_login = $1
344 LIMIT 1
345 ",
346 )
347 .bind(github_login)
348 .fetch_optional(&self.pool)
349 .await?)
350 }
351 }
352
353 async fn set_user_is_admin(&self, id: UserId, is_admin: bool) -> Result<()> {
354 let query = "UPDATE users SET admin = $1 WHERE id = $2";
355 Ok(sqlx::query(query)
356 .bind(is_admin)
357 .bind(id.0)
358 .execute(&self.pool)
359 .await
360 .map(drop)?)
361 }
362
363 async fn set_user_connected_once(&self, id: UserId, connected_once: bool) -> Result<()> {
364 let query = "UPDATE users SET connected_once = $1 WHERE id = $2";
365 Ok(sqlx::query(query)
366 .bind(connected_once)
367 .bind(id.0)
368 .execute(&self.pool)
369 .await
370 .map(drop)?)
371 }
372
373 async fn destroy_user(&self, id: UserId) -> Result<()> {
374 let query = "DELETE FROM access_tokens WHERE user_id = $1;";
375 sqlx::query(query)
376 .bind(id.0)
377 .execute(&self.pool)
378 .await
379 .map(drop)?;
380 let query = "DELETE FROM users WHERE id = $1;";
381 Ok(sqlx::query(query)
382 .bind(id.0)
383 .execute(&self.pool)
384 .await
385 .map(drop)?)
386 }
387
388 // signups
389
390 async fn create_signup(&self, signup: Signup) -> Result<()> {
391 sqlx::query(
392 "
393 INSERT INTO signups
394 (
395 email_address,
396 email_confirmation_code,
397 email_confirmation_sent,
398 platform_linux,
399 platform_mac,
400 platform_windows,
401 platform_unknown,
402 editor_features,
403 programming_languages,
404 device_id
405 )
406 VALUES
407 ($1, $2, 'f', $3, $4, $5, 'f', $6, $7, $8)
408 RETURNING id
409 ",
410 )
411 .bind(&signup.email_address)
412 .bind(&random_email_confirmation_code())
413 .bind(&signup.platform_linux)
414 .bind(&signup.platform_mac)
415 .bind(&signup.platform_windows)
416 .bind(&signup.editor_features)
417 .bind(&signup.programming_languages)
418 .bind(&signup.device_id)
419 .execute(&self.pool)
420 .await?;
421 Ok(())
422 }
423
424 async fn get_waitlist_summary(&self) -> Result<WaitlistSummary> {
425 Ok(sqlx::query_as(
426 "
427 SELECT
428 COUNT(*) as count,
429 COALESCE(SUM(CASE WHEN platform_linux THEN 1 ELSE 0 END), 0) as linux_count,
430 COALESCE(SUM(CASE WHEN platform_mac THEN 1 ELSE 0 END), 0) as mac_count,
431 COALESCE(SUM(CASE WHEN platform_windows THEN 1 ELSE 0 END), 0) as windows_count
432 FROM (
433 SELECT *
434 FROM signups
435 WHERE
436 NOT email_confirmation_sent
437 ) AS unsent
438 ",
439 )
440 .fetch_one(&self.pool)
441 .await?)
442 }
443
444 async fn get_unsent_invites(&self, count: usize) -> Result<Vec<Invite>> {
445 Ok(sqlx::query_as(
446 "
447 SELECT
448 email_address, email_confirmation_code
449 FROM signups
450 WHERE
451 NOT email_confirmation_sent AND
452 platform_mac
453 LIMIT $1
454 ",
455 )
456 .bind(count as i32)
457 .fetch_all(&self.pool)
458 .await?)
459 }
460
461 async fn record_sent_invites(&self, invites: &[Invite]) -> Result<()> {
462 sqlx::query(
463 "
464 UPDATE signups
465 SET email_confirmation_sent = 't'
466 WHERE email_address = ANY ($1)
467 ",
468 )
469 .bind(
470 &invites
471 .iter()
472 .map(|s| s.email_address.as_str())
473 .collect::<Vec<_>>(),
474 )
475 .execute(&self.pool)
476 .await?;
477 Ok(())
478 }
479
480 async fn create_user_from_invite(
481 &self,
482 invite: &Invite,
483 user: NewUserParams,
484 ) -> Result<NewUserResult> {
485 let mut tx = self.pool.begin().await?;
486
487 let (signup_id, existing_user_id, inviting_user_id, signup_device_id): (
488 i32,
489 Option<UserId>,
490 Option<UserId>,
491 Option<String>,
492 ) = sqlx::query_as(
493 "
494 SELECT id, user_id, inviting_user_id, device_id
495 FROM signups
496 WHERE
497 email_address = $1 AND
498 email_confirmation_code = $2
499 ",
500 )
501 .bind(&invite.email_address)
502 .bind(&invite.email_confirmation_code)
503 .fetch_optional(&mut tx)
504 .await?
505 .ok_or_else(|| Error::Http(StatusCode::NOT_FOUND, "no such invite".to_string()))?;
506
507 if existing_user_id.is_some() {
508 Err(Error::Http(
509 StatusCode::UNPROCESSABLE_ENTITY,
510 "invitation already redeemed".to_string(),
511 ))?;
512 }
513
514 let (user_id, metrics_id): (UserId, String) = sqlx::query_as(
515 "
516 INSERT INTO users
517 (email_address, github_login, github_user_id, admin, invite_count, invite_code)
518 VALUES
519 ($1, $2, $3, 'f', $4, $5)
520 RETURNING id, metrics_id::text
521 ",
522 )
523 .bind(&invite.email_address)
524 .bind(&user.github_login)
525 .bind(&user.github_user_id)
526 .bind(&user.invite_count)
527 .bind(random_invite_code())
528 .fetch_one(&mut tx)
529 .await?;
530
531 sqlx::query(
532 "
533 UPDATE signups
534 SET user_id = $1
535 WHERE id = $2
536 ",
537 )
538 .bind(&user_id)
539 .bind(&signup_id)
540 .execute(&mut tx)
541 .await?;
542
543 if let Some(inviting_user_id) = inviting_user_id {
544 let id: Option<UserId> = sqlx::query_scalar(
545 "
546 UPDATE users
547 SET invite_count = invite_count - 1
548 WHERE id = $1 AND invite_count > 0
549 RETURNING id
550 ",
551 )
552 .bind(&inviting_user_id)
553 .fetch_optional(&mut tx)
554 .await?;
555
556 if id.is_none() {
557 Err(Error::Http(
558 StatusCode::UNAUTHORIZED,
559 "no invites remaining".to_string(),
560 ))?;
561 }
562
563 sqlx::query(
564 "
565 INSERT INTO contacts
566 (user_id_a, user_id_b, a_to_b, should_notify, accepted)
567 VALUES
568 ($1, $2, 't', 't', 't')
569 ",
570 )
571 .bind(inviting_user_id)
572 .bind(user_id)
573 .execute(&mut tx)
574 .await?;
575 }
576
577 tx.commit().await?;
578 Ok(NewUserResult {
579 user_id,
580 metrics_id,
581 inviting_user_id,
582 signup_device_id,
583 })
584 }
585
586 // invite codes
587
588 async fn set_invite_count_for_user(&self, id: UserId, count: u32) -> Result<()> {
589 let mut tx = self.pool.begin().await?;
590 if count > 0 {
591 sqlx::query(
592 "
593 UPDATE users
594 SET invite_code = $1
595 WHERE id = $2 AND invite_code IS NULL
596 ",
597 )
598 .bind(random_invite_code())
599 .bind(id)
600 .execute(&mut tx)
601 .await?;
602 }
603
604 sqlx::query(
605 "
606 UPDATE users
607 SET invite_count = $1
608 WHERE id = $2
609 ",
610 )
611 .bind(count as i32)
612 .bind(id)
613 .execute(&mut tx)
614 .await?;
615 tx.commit().await?;
616 Ok(())
617 }
618
619 async fn get_invite_code_for_user(&self, id: UserId) -> Result<Option<(String, u32)>> {
620 let result: Option<(String, i32)> = sqlx::query_as(
621 "
622 SELECT invite_code, invite_count
623 FROM users
624 WHERE id = $1 AND invite_code IS NOT NULL
625 ",
626 )
627 .bind(id)
628 .fetch_optional(&self.pool)
629 .await?;
630 if let Some((code, count)) = result {
631 Ok(Some((code, count.try_into().map_err(anyhow::Error::new)?)))
632 } else {
633 Ok(None)
634 }
635 }
636
637 async fn get_user_for_invite_code(&self, code: &str) -> Result<User> {
638 sqlx::query_as(
639 "
640 SELECT *
641 FROM users
642 WHERE invite_code = $1
643 ",
644 )
645 .bind(code)
646 .fetch_optional(&self.pool)
647 .await?
648 .ok_or_else(|| {
649 Error::Http(
650 StatusCode::NOT_FOUND,
651 "that invite code does not exist".to_string(),
652 )
653 })
654 }
655
656 async fn create_invite_from_code(
657 &self,
658 code: &str,
659 email_address: &str,
660 device_id: Option<&str>,
661 ) -> Result<Invite> {
662 let mut tx = self.pool.begin().await?;
663
664 let existing_user: Option<UserId> = sqlx::query_scalar(
665 "
666 SELECT id
667 FROM users
668 WHERE email_address = $1
669 ",
670 )
671 .bind(email_address)
672 .fetch_optional(&mut tx)
673 .await?;
674 if existing_user.is_some() {
675 Err(anyhow!("email address is already in use"))?;
676 }
677
678 let row: Option<(UserId, i32)> = sqlx::query_as(
679 "
680 SELECT id, invite_count
681 FROM users
682 WHERE invite_code = $1
683 ",
684 )
685 .bind(code)
686 .fetch_optional(&mut tx)
687 .await?;
688
689 let (inviter_id, invite_count) = match row {
690 Some(row) => row,
691 None => Err(Error::Http(
692 StatusCode::NOT_FOUND,
693 "invite code not found".to_string(),
694 ))?,
695 };
696
697 if invite_count == 0 {
698 Err(Error::Http(
699 StatusCode::UNAUTHORIZED,
700 "no invites remaining".to_string(),
701 ))?;
702 }
703
704 let email_confirmation_code: String = sqlx::query_scalar(
705 "
706 INSERT INTO signups
707 (
708 email_address,
709 email_confirmation_code,
710 email_confirmation_sent,
711 inviting_user_id,
712 platform_linux,
713 platform_mac,
714 platform_windows,
715 platform_unknown,
716 device_id
717 )
718 VALUES
719 ($1, $2, 'f', $3, 'f', 'f', 'f', 't', $4)
720 ON CONFLICT (email_address)
721 DO UPDATE SET
722 inviting_user_id = excluded.inviting_user_id
723 RETURNING email_confirmation_code
724 ",
725 )
726 .bind(&email_address)
727 .bind(&random_email_confirmation_code())
728 .bind(&inviter_id)
729 .bind(&device_id)
730 .fetch_one(&mut tx)
731 .await?;
732
733 tx.commit().await?;
734
735 Ok(Invite {
736 email_address: email_address.into(),
737 email_confirmation_code,
738 })
739 }
740
741 // projects
742
743 async fn register_project(&self, host_user_id: UserId) -> Result<ProjectId> {
744 Ok(sqlx::query_scalar(
745 "
746 INSERT INTO projects(host_user_id)
747 VALUES ($1)
748 RETURNING id
749 ",
750 )
751 .bind(host_user_id)
752 .fetch_one(&self.pool)
753 .await
754 .map(ProjectId)?)
755 }
756
757 async fn unregister_project(&self, project_id: ProjectId) -> Result<()> {
758 sqlx::query(
759 "
760 UPDATE projects
761 SET unregistered = 't'
762 WHERE id = $1
763 ",
764 )
765 .bind(project_id)
766 .execute(&self.pool)
767 .await?;
768 Ok(())
769 }
770
771 async fn update_worktree_extensions(
772 &self,
773 project_id: ProjectId,
774 worktree_id: u64,
775 extensions: HashMap<String, u32>,
776 ) -> Result<()> {
777 if extensions.is_empty() {
778 return Ok(());
779 }
780
781 let mut query = QueryBuilder::new(
782 "INSERT INTO worktree_extensions (project_id, worktree_id, extension, count)",
783 );
784 query.push_values(extensions, |mut query, (extension, count)| {
785 query
786 .push_bind(project_id)
787 .push_bind(worktree_id as i32)
788 .push_bind(extension)
789 .push_bind(count as i32);
790 });
791 query.push(
792 "
793 ON CONFLICT (project_id, worktree_id, extension) DO UPDATE SET
794 count = excluded.count
795 ",
796 );
797 query.build().execute(&self.pool).await?;
798
799 Ok(())
800 }
801
802 async fn get_project_extensions(
803 &self,
804 project_id: ProjectId,
805 ) -> Result<HashMap<u64, HashMap<String, usize>>> {
806 #[derive(Clone, Debug, Default, FromRow, Serialize, PartialEq)]
807 struct WorktreeExtension {
808 worktree_id: i32,
809 extension: String,
810 count: i32,
811 }
812
813 let query = "
814 SELECT worktree_id, extension, count
815 FROM worktree_extensions
816 WHERE project_id = $1
817 ";
818 let counts = sqlx::query_as::<_, WorktreeExtension>(query)
819 .bind(&project_id)
820 .fetch_all(&self.pool)
821 .await?;
822
823 let mut extension_counts = HashMap::default();
824 for count in counts {
825 extension_counts
826 .entry(count.worktree_id as u64)
827 .or_insert_with(HashMap::default)
828 .insert(count.extension, count.count as usize);
829 }
830 Ok(extension_counts)
831 }
832
833 async fn record_user_activity(
834 &self,
835 time_period: Range<OffsetDateTime>,
836 projects: &[(UserId, ProjectId)],
837 ) -> Result<()> {
838 let query = "
839 INSERT INTO project_activity_periods
840 (ended_at, duration_millis, user_id, project_id)
841 VALUES
842 ($1, $2, $3, $4);
843 ";
844
845 let mut tx = self.pool.begin().await?;
846 let duration_millis =
847 ((time_period.end - time_period.start).as_seconds_f64() * 1000.0) as i32;
848 for (user_id, project_id) in projects {
849 sqlx::query(query)
850 .bind(time_period.end)
851 .bind(duration_millis)
852 .bind(user_id)
853 .bind(project_id)
854 .execute(&mut tx)
855 .await?;
856 }
857 tx.commit().await?;
858
859 Ok(())
860 }
861
862 async fn get_active_user_count(
863 &self,
864 time_period: Range<OffsetDateTime>,
865 min_duration: Duration,
866 only_collaborative: bool,
867 ) -> Result<usize> {
868 let mut with_clause = String::new();
869 with_clause.push_str("WITH\n");
870 with_clause.push_str(
871 "
872 project_durations AS (
873 SELECT user_id, project_id, SUM(duration_millis) AS project_duration
874 FROM project_activity_periods
875 WHERE $1 < ended_at AND ended_at <= $2
876 GROUP BY user_id, project_id
877 ),
878 ",
879 );
880 with_clause.push_str(
881 "
882 project_collaborators as (
883 SELECT project_id, COUNT(DISTINCT user_id) as max_collaborators
884 FROM project_durations
885 GROUP BY project_id
886 ),
887 ",
888 );
889
890 if only_collaborative {
891 with_clause.push_str(
892 "
893 user_durations AS (
894 SELECT user_id, SUM(project_duration) as total_duration
895 FROM project_durations, project_collaborators
896 WHERE
897 project_durations.project_id = project_collaborators.project_id AND
898 max_collaborators > 1
899 GROUP BY user_id
900 ORDER BY total_duration DESC
901 LIMIT $3
902 )
903 ",
904 );
905 } else {
906 with_clause.push_str(
907 "
908 user_durations AS (
909 SELECT user_id, SUM(project_duration) as total_duration
910 FROM project_durations
911 GROUP BY user_id
912 ORDER BY total_duration DESC
913 LIMIT $3
914 )
915 ",
916 );
917 }
918
919 let query = format!(
920 "
921 {with_clause}
922 SELECT count(user_durations.user_id)
923 FROM user_durations
924 WHERE user_durations.total_duration >= $3
925 "
926 );
927
928 let count: i64 = sqlx::query_scalar(&query)
929 .bind(time_period.start)
930 .bind(time_period.end)
931 .bind(min_duration.as_millis() as i64)
932 .fetch_one(&self.pool)
933 .await?;
934 Ok(count as usize)
935 }
936
937 async fn get_top_users_activity_summary(
938 &self,
939 time_period: Range<OffsetDateTime>,
940 max_user_count: usize,
941 ) -> Result<Vec<UserActivitySummary>> {
942 let query = "
943 WITH
944 project_durations AS (
945 SELECT user_id, project_id, SUM(duration_millis) AS project_duration
946 FROM project_activity_periods
947 WHERE $1 < ended_at AND ended_at <= $2
948 GROUP BY user_id, project_id
949 ),
950 user_durations AS (
951 SELECT user_id, SUM(project_duration) as total_duration
952 FROM project_durations
953 GROUP BY user_id
954 ORDER BY total_duration DESC
955 LIMIT $3
956 ),
957 project_collaborators as (
958 SELECT project_id, COUNT(DISTINCT user_id) as max_collaborators
959 FROM project_durations
960 GROUP BY project_id
961 )
962 SELECT user_durations.user_id, users.github_login, project_durations.project_id, project_duration, max_collaborators
963 FROM user_durations, project_durations, project_collaborators, users
964 WHERE
965 user_durations.user_id = project_durations.user_id AND
966 user_durations.user_id = users.id AND
967 project_durations.project_id = project_collaborators.project_id
968 ORDER BY total_duration DESC, user_id ASC, project_id ASC
969 ";
970
971 let mut rows = sqlx::query_as::<_, (UserId, String, ProjectId, i64, i64)>(query)
972 .bind(time_period.start)
973 .bind(time_period.end)
974 .bind(max_user_count as i32)
975 .fetch(&self.pool);
976
977 let mut result = Vec::<UserActivitySummary>::new();
978 while let Some(row) = rows.next().await {
979 let (user_id, github_login, project_id, duration_millis, project_collaborators) = row?;
980 let project_id = project_id;
981 let duration = Duration::from_millis(duration_millis as u64);
982 let project_activity = ProjectActivitySummary {
983 id: project_id,
984 duration,
985 max_collaborators: project_collaborators as usize,
986 };
987 if let Some(last_summary) = result.last_mut() {
988 if last_summary.id == user_id {
989 last_summary.project_activity.push(project_activity);
990 continue;
991 }
992 }
993 result.push(UserActivitySummary {
994 id: user_id,
995 project_activity: vec![project_activity],
996 github_login,
997 });
998 }
999
1000 Ok(result)
1001 }
1002
1003 async fn get_user_activity_timeline(
1004 &self,
1005 time_period: Range<OffsetDateTime>,
1006 user_id: UserId,
1007 ) -> Result<Vec<UserActivityPeriod>> {
1008 const COALESCE_THRESHOLD: Duration = Duration::from_secs(30);
1009
1010 let query = "
1011 SELECT
1012 project_activity_periods.ended_at,
1013 project_activity_periods.duration_millis,
1014 project_activity_periods.project_id,
1015 worktree_extensions.extension,
1016 worktree_extensions.count
1017 FROM project_activity_periods
1018 LEFT OUTER JOIN
1019 worktree_extensions
1020 ON
1021 project_activity_periods.project_id = worktree_extensions.project_id
1022 WHERE
1023 project_activity_periods.user_id = $1 AND
1024 $2 < project_activity_periods.ended_at AND
1025 project_activity_periods.ended_at <= $3
1026 ORDER BY project_activity_periods.id ASC
1027 ";
1028
1029 let mut rows = sqlx::query_as::<
1030 _,
1031 (
1032 PrimitiveDateTime,
1033 i32,
1034 ProjectId,
1035 Option<String>,
1036 Option<i32>,
1037 ),
1038 >(query)
1039 .bind(user_id)
1040 .bind(time_period.start)
1041 .bind(time_period.end)
1042 .fetch(&self.pool);
1043
1044 let mut time_periods: HashMap<ProjectId, Vec<UserActivityPeriod>> = Default::default();
1045 while let Some(row) = rows.next().await {
1046 let (ended_at, duration_millis, project_id, extension, extension_count) = row?;
1047 let ended_at = ended_at.assume_utc();
1048 let duration = Duration::from_millis(duration_millis as u64);
1049 let started_at = ended_at - duration;
1050 let project_time_periods = time_periods.entry(project_id).or_default();
1051
1052 if let Some(prev_duration) = project_time_periods.last_mut() {
1053 if started_at <= prev_duration.end + COALESCE_THRESHOLD
1054 && ended_at >= prev_duration.start
1055 {
1056 prev_duration.end = cmp::max(prev_duration.end, ended_at);
1057 } else {
1058 project_time_periods.push(UserActivityPeriod {
1059 project_id,
1060 start: started_at,
1061 end: ended_at,
1062 extensions: Default::default(),
1063 });
1064 }
1065 } else {
1066 project_time_periods.push(UserActivityPeriod {
1067 project_id,
1068 start: started_at,
1069 end: ended_at,
1070 extensions: Default::default(),
1071 });
1072 }
1073
1074 if let Some((extension, extension_count)) = extension.zip(extension_count) {
1075 project_time_periods
1076 .last_mut()
1077 .unwrap()
1078 .extensions
1079 .insert(extension, extension_count as usize);
1080 }
1081 }
1082
1083 let mut durations = time_periods.into_values().flatten().collect::<Vec<_>>();
1084 durations.sort_unstable_by_key(|duration| duration.start);
1085 Ok(durations)
1086 }
1087
1088 // contacts
1089
1090 async fn get_contacts(&self, user_id: UserId) -> Result<Vec<Contact>> {
1091 let query = "
1092 SELECT user_id_a, user_id_b, a_to_b, accepted, should_notify
1093 FROM contacts
1094 WHERE user_id_a = $1 OR user_id_b = $1;
1095 ";
1096
1097 let mut rows = sqlx::query_as::<_, (UserId, UserId, bool, bool, bool)>(query)
1098 .bind(user_id)
1099 .fetch(&self.pool);
1100
1101 let mut contacts = vec![Contact::Accepted {
1102 user_id,
1103 should_notify: false,
1104 }];
1105 while let Some(row) = rows.next().await {
1106 let (user_id_a, user_id_b, a_to_b, accepted, should_notify) = row?;
1107
1108 if user_id_a == user_id {
1109 if accepted {
1110 contacts.push(Contact::Accepted {
1111 user_id: user_id_b,
1112 should_notify: should_notify && a_to_b,
1113 });
1114 } else if a_to_b {
1115 contacts.push(Contact::Outgoing { user_id: user_id_b })
1116 } else {
1117 contacts.push(Contact::Incoming {
1118 user_id: user_id_b,
1119 should_notify,
1120 });
1121 }
1122 } else if accepted {
1123 contacts.push(Contact::Accepted {
1124 user_id: user_id_a,
1125 should_notify: should_notify && !a_to_b,
1126 });
1127 } else if a_to_b {
1128 contacts.push(Contact::Incoming {
1129 user_id: user_id_a,
1130 should_notify,
1131 });
1132 } else {
1133 contacts.push(Contact::Outgoing { user_id: user_id_a });
1134 }
1135 }
1136
1137 contacts.sort_unstable_by_key(|contact| contact.user_id());
1138
1139 Ok(contacts)
1140 }
1141
1142 async fn has_contact(&self, user_id_1: UserId, user_id_2: UserId) -> Result<bool> {
1143 let (id_a, id_b) = if user_id_1 < user_id_2 {
1144 (user_id_1, user_id_2)
1145 } else {
1146 (user_id_2, user_id_1)
1147 };
1148
1149 let query = "
1150 SELECT 1 FROM contacts
1151 WHERE user_id_a = $1 AND user_id_b = $2 AND accepted = 't'
1152 LIMIT 1
1153 ";
1154 Ok(sqlx::query_scalar::<_, i32>(query)
1155 .bind(id_a.0)
1156 .bind(id_b.0)
1157 .fetch_optional(&self.pool)
1158 .await?
1159 .is_some())
1160 }
1161
1162 async fn send_contact_request(&self, sender_id: UserId, receiver_id: UserId) -> Result<()> {
1163 let (id_a, id_b, a_to_b) = if sender_id < receiver_id {
1164 (sender_id, receiver_id, true)
1165 } else {
1166 (receiver_id, sender_id, false)
1167 };
1168 let query = "
1169 INSERT into contacts (user_id_a, user_id_b, a_to_b, accepted, should_notify)
1170 VALUES ($1, $2, $3, 'f', 't')
1171 ON CONFLICT (user_id_a, user_id_b) DO UPDATE
1172 SET
1173 accepted = 't',
1174 should_notify = 'f'
1175 WHERE
1176 NOT contacts.accepted AND
1177 ((contacts.a_to_b = excluded.a_to_b AND contacts.user_id_a = excluded.user_id_b) OR
1178 (contacts.a_to_b != excluded.a_to_b AND contacts.user_id_a = excluded.user_id_a));
1179 ";
1180 let result = sqlx::query(query)
1181 .bind(id_a.0)
1182 .bind(id_b.0)
1183 .bind(a_to_b)
1184 .execute(&self.pool)
1185 .await?;
1186
1187 if result.rows_affected() == 1 {
1188 Ok(())
1189 } else {
1190 Err(anyhow!("contact already requested"))?
1191 }
1192 }
1193
1194 async fn remove_contact(&self, requester_id: UserId, responder_id: UserId) -> Result<()> {
1195 let (id_a, id_b) = if responder_id < requester_id {
1196 (responder_id, requester_id)
1197 } else {
1198 (requester_id, responder_id)
1199 };
1200 let query = "
1201 DELETE FROM contacts
1202 WHERE user_id_a = $1 AND user_id_b = $2;
1203 ";
1204 let result = sqlx::query(query)
1205 .bind(id_a.0)
1206 .bind(id_b.0)
1207 .execute(&self.pool)
1208 .await?;
1209
1210 if result.rows_affected() == 1 {
1211 Ok(())
1212 } else {
1213 Err(anyhow!("no such contact"))?
1214 }
1215 }
1216
1217 async fn dismiss_contact_notification(
1218 &self,
1219 user_id: UserId,
1220 contact_user_id: UserId,
1221 ) -> Result<()> {
1222 let (id_a, id_b, a_to_b) = if user_id < contact_user_id {
1223 (user_id, contact_user_id, true)
1224 } else {
1225 (contact_user_id, user_id, false)
1226 };
1227
1228 let query = "
1229 UPDATE contacts
1230 SET should_notify = 'f'
1231 WHERE
1232 user_id_a = $1 AND user_id_b = $2 AND
1233 (
1234 (a_to_b = $3 AND accepted) OR
1235 (a_to_b != $3 AND NOT accepted)
1236 );
1237 ";
1238
1239 let result = sqlx::query(query)
1240 .bind(id_a.0)
1241 .bind(id_b.0)
1242 .bind(a_to_b)
1243 .execute(&self.pool)
1244 .await?;
1245
1246 if result.rows_affected() == 0 {
1247 Err(anyhow!("no such contact request"))?;
1248 }
1249
1250 Ok(())
1251 }
1252
1253 async fn respond_to_contact_request(
1254 &self,
1255 responder_id: UserId,
1256 requester_id: UserId,
1257 accept: bool,
1258 ) -> Result<()> {
1259 let (id_a, id_b, a_to_b) = if responder_id < requester_id {
1260 (responder_id, requester_id, false)
1261 } else {
1262 (requester_id, responder_id, true)
1263 };
1264 let result = if accept {
1265 let query = "
1266 UPDATE contacts
1267 SET accepted = 't', should_notify = 't'
1268 WHERE user_id_a = $1 AND user_id_b = $2 AND a_to_b = $3;
1269 ";
1270 sqlx::query(query)
1271 .bind(id_a.0)
1272 .bind(id_b.0)
1273 .bind(a_to_b)
1274 .execute(&self.pool)
1275 .await?
1276 } else {
1277 let query = "
1278 DELETE FROM contacts
1279 WHERE user_id_a = $1 AND user_id_b = $2 AND a_to_b = $3 AND NOT accepted;
1280 ";
1281 sqlx::query(query)
1282 .bind(id_a.0)
1283 .bind(id_b.0)
1284 .bind(a_to_b)
1285 .execute(&self.pool)
1286 .await?
1287 };
1288 if result.rows_affected() == 1 {
1289 Ok(())
1290 } else {
1291 Err(anyhow!("no such contact request"))?
1292 }
1293 }
1294
1295 // access tokens
1296
1297 async fn create_access_token_hash(
1298 &self,
1299 user_id: UserId,
1300 access_token_hash: &str,
1301 max_access_token_count: usize,
1302 ) -> Result<()> {
1303 let insert_query = "
1304 INSERT INTO access_tokens (user_id, hash)
1305 VALUES ($1, $2);
1306 ";
1307 let cleanup_query = "
1308 DELETE FROM access_tokens
1309 WHERE id IN (
1310 SELECT id from access_tokens
1311 WHERE user_id = $1
1312 ORDER BY id DESC
1313 OFFSET $3
1314 )
1315 ";
1316
1317 let mut tx = self.pool.begin().await?;
1318 sqlx::query(insert_query)
1319 .bind(user_id.0)
1320 .bind(access_token_hash)
1321 .execute(&mut tx)
1322 .await?;
1323 sqlx::query(cleanup_query)
1324 .bind(user_id.0)
1325 .bind(access_token_hash)
1326 .bind(max_access_token_count as i32)
1327 .execute(&mut tx)
1328 .await?;
1329 Ok(tx.commit().await?)
1330 }
1331
1332 async fn get_access_token_hashes(&self, user_id: UserId) -> Result<Vec<String>> {
1333 let query = "
1334 SELECT hash
1335 FROM access_tokens
1336 WHERE user_id = $1
1337 ORDER BY id DESC
1338 ";
1339 Ok(sqlx::query_scalar(query)
1340 .bind(user_id.0)
1341 .fetch_all(&self.pool)
1342 .await?)
1343 }
1344
1345 // orgs
1346
1347 #[allow(unused)] // Help rust-analyzer
1348 #[cfg(any(test, feature = "seed-support"))]
1349 async fn find_org_by_slug(&self, slug: &str) -> Result<Option<Org>> {
1350 let query = "
1351 SELECT *
1352 FROM orgs
1353 WHERE slug = $1
1354 ";
1355 Ok(sqlx::query_as(query)
1356 .bind(slug)
1357 .fetch_optional(&self.pool)
1358 .await?)
1359 }
1360
1361 #[cfg(any(test, feature = "seed-support"))]
1362 async fn create_org(&self, name: &str, slug: &str) -> Result<OrgId> {
1363 let query = "
1364 INSERT INTO orgs (name, slug)
1365 VALUES ($1, $2)
1366 RETURNING id
1367 ";
1368 Ok(sqlx::query_scalar(query)
1369 .bind(name)
1370 .bind(slug)
1371 .fetch_one(&self.pool)
1372 .await
1373 .map(OrgId)?)
1374 }
1375
1376 #[cfg(any(test, feature = "seed-support"))]
1377 async fn add_org_member(&self, org_id: OrgId, user_id: UserId, is_admin: bool) -> Result<()> {
1378 let query = "
1379 INSERT INTO org_memberships (org_id, user_id, admin)
1380 VALUES ($1, $2, $3)
1381 ON CONFLICT DO NOTHING
1382 ";
1383 Ok(sqlx::query(query)
1384 .bind(org_id.0)
1385 .bind(user_id.0)
1386 .bind(is_admin)
1387 .execute(&self.pool)
1388 .await
1389 .map(drop)?)
1390 }
1391
1392 // channels
1393
1394 #[cfg(any(test, feature = "seed-support"))]
1395 async fn create_org_channel(&self, org_id: OrgId, name: &str) -> Result<ChannelId> {
1396 let query = "
1397 INSERT INTO channels (owner_id, owner_is_user, name)
1398 VALUES ($1, false, $2)
1399 RETURNING id
1400 ";
1401 Ok(sqlx::query_scalar(query)
1402 .bind(org_id.0)
1403 .bind(name)
1404 .fetch_one(&self.pool)
1405 .await
1406 .map(ChannelId)?)
1407 }
1408
1409 #[allow(unused)] // Help rust-analyzer
1410 #[cfg(any(test, feature = "seed-support"))]
1411 async fn get_org_channels(&self, org_id: OrgId) -> Result<Vec<Channel>> {
1412 let query = "
1413 SELECT *
1414 FROM channels
1415 WHERE
1416 channels.owner_is_user = false AND
1417 channels.owner_id = $1
1418 ";
1419 Ok(sqlx::query_as(query)
1420 .bind(org_id.0)
1421 .fetch_all(&self.pool)
1422 .await?)
1423 }
1424
1425 async fn get_accessible_channels(&self, user_id: UserId) -> Result<Vec<Channel>> {
1426 let query = "
1427 SELECT
1428 channels.*
1429 FROM
1430 channel_memberships, channels
1431 WHERE
1432 channel_memberships.user_id = $1 AND
1433 channel_memberships.channel_id = channels.id
1434 ";
1435 Ok(sqlx::query_as(query)
1436 .bind(user_id.0)
1437 .fetch_all(&self.pool)
1438 .await?)
1439 }
1440
1441 async fn can_user_access_channel(
1442 &self,
1443 user_id: UserId,
1444 channel_id: ChannelId,
1445 ) -> Result<bool> {
1446 let query = "
1447 SELECT id
1448 FROM channel_memberships
1449 WHERE user_id = $1 AND channel_id = $2
1450 LIMIT 1
1451 ";
1452 Ok(sqlx::query_scalar::<_, i32>(query)
1453 .bind(user_id.0)
1454 .bind(channel_id.0)
1455 .fetch_optional(&self.pool)
1456 .await
1457 .map(|e| e.is_some())?)
1458 }
1459
1460 #[cfg(any(test, feature = "seed-support"))]
1461 async fn add_channel_member(
1462 &self,
1463 channel_id: ChannelId,
1464 user_id: UserId,
1465 is_admin: bool,
1466 ) -> Result<()> {
1467 let query = "
1468 INSERT INTO channel_memberships (channel_id, user_id, admin)
1469 VALUES ($1, $2, $3)
1470 ON CONFLICT DO NOTHING
1471 ";
1472 Ok(sqlx::query(query)
1473 .bind(channel_id.0)
1474 .bind(user_id.0)
1475 .bind(is_admin)
1476 .execute(&self.pool)
1477 .await
1478 .map(drop)?)
1479 }
1480
1481 // messages
1482
1483 async fn create_channel_message(
1484 &self,
1485 channel_id: ChannelId,
1486 sender_id: UserId,
1487 body: &str,
1488 timestamp: OffsetDateTime,
1489 nonce: u128,
1490 ) -> Result<MessageId> {
1491 let query = "
1492 INSERT INTO channel_messages (channel_id, sender_id, body, sent_at, nonce)
1493 VALUES ($1, $2, $3, $4, $5)
1494 ON CONFLICT (nonce) DO UPDATE SET nonce = excluded.nonce
1495 RETURNING id
1496 ";
1497 Ok(sqlx::query_scalar(query)
1498 .bind(channel_id.0)
1499 .bind(sender_id.0)
1500 .bind(body)
1501 .bind(timestamp)
1502 .bind(Uuid::from_u128(nonce))
1503 .fetch_one(&self.pool)
1504 .await
1505 .map(MessageId)?)
1506 }
1507
1508 async fn get_channel_messages(
1509 &self,
1510 channel_id: ChannelId,
1511 count: usize,
1512 before_id: Option<MessageId>,
1513 ) -> Result<Vec<ChannelMessage>> {
1514 let query = r#"
1515 SELECT * FROM (
1516 SELECT
1517 id, channel_id, sender_id, body, sent_at AT TIME ZONE 'UTC' as sent_at, nonce
1518 FROM
1519 channel_messages
1520 WHERE
1521 channel_id = $1 AND
1522 id < $2
1523 ORDER BY id DESC
1524 LIMIT $3
1525 ) as recent_messages
1526 ORDER BY id ASC
1527 "#;
1528 Ok(sqlx::query_as(query)
1529 .bind(channel_id.0)
1530 .bind(before_id.unwrap_or(MessageId::MAX))
1531 .bind(count as i64)
1532 .fetch_all(&self.pool)
1533 .await?)
1534 }
1535
1536 #[cfg(test)]
1537 async fn teardown(&self, url: &str) {
1538 use util::ResultExt;
1539
1540 let query = "
1541 SELECT pg_terminate_backend(pg_stat_activity.pid)
1542 FROM pg_stat_activity
1543 WHERE pg_stat_activity.datname = current_database() AND pid <> pg_backend_pid();
1544 ";
1545 sqlx::query(query).execute(&self.pool).await.log_err();
1546 self.pool.close().await;
1547 <sqlx::Postgres as sqlx::migrate::MigrateDatabase>::drop_database(url)
1548 .await
1549 .log_err();
1550 }
1551
1552 #[cfg(test)]
1553 fn as_fake(&self) -> Option<&FakeDb> {
1554 None
1555 }
1556}
1557
1558macro_rules! id_type {
1559 ($name:ident) => {
1560 #[derive(
1561 Clone,
1562 Copy,
1563 Debug,
1564 Default,
1565 PartialEq,
1566 Eq,
1567 PartialOrd,
1568 Ord,
1569 Hash,
1570 sqlx::Type,
1571 Serialize,
1572 Deserialize,
1573 )]
1574 #[sqlx(transparent)]
1575 #[serde(transparent)]
1576 pub struct $name(pub i32);
1577
1578 impl $name {
1579 #[allow(unused)]
1580 pub const MAX: Self = Self(i32::MAX);
1581
1582 #[allow(unused)]
1583 pub fn from_proto(value: u64) -> Self {
1584 Self(value as i32)
1585 }
1586
1587 #[allow(unused)]
1588 pub fn to_proto(self) -> u64 {
1589 self.0 as u64
1590 }
1591 }
1592
1593 impl std::fmt::Display for $name {
1594 fn fmt(&self, f: &mut std::fmt::Formatter) -> std::fmt::Result {
1595 self.0.fmt(f)
1596 }
1597 }
1598 };
1599}
1600
1601id_type!(UserId);
1602#[derive(Clone, Debug, Default, FromRow, Serialize, PartialEq)]
1603pub struct User {
1604 pub id: UserId,
1605 pub github_login: String,
1606 pub github_user_id: Option<i32>,
1607 pub email_address: Option<String>,
1608 pub admin: bool,
1609 pub invite_code: Option<String>,
1610 pub invite_count: i32,
1611 pub connected_once: bool,
1612}
1613
1614id_type!(ProjectId);
1615#[derive(Clone, Debug, Default, FromRow, Serialize, PartialEq)]
1616pub struct Project {
1617 pub id: ProjectId,
1618 pub host_user_id: UserId,
1619 pub unregistered: bool,
1620}
1621
1622#[derive(Clone, Debug, PartialEq, Serialize)]
1623pub struct UserActivitySummary {
1624 pub id: UserId,
1625 pub github_login: String,
1626 pub project_activity: Vec<ProjectActivitySummary>,
1627}
1628
1629#[derive(Clone, Debug, PartialEq, Serialize)]
1630pub struct ProjectActivitySummary {
1631 pub id: ProjectId,
1632 pub duration: Duration,
1633 pub max_collaborators: usize,
1634}
1635
1636#[derive(Clone, Debug, PartialEq, Serialize)]
1637pub struct UserActivityPeriod {
1638 pub project_id: ProjectId,
1639 #[serde(with = "time::serde::iso8601")]
1640 pub start: OffsetDateTime,
1641 #[serde(with = "time::serde::iso8601")]
1642 pub end: OffsetDateTime,
1643 pub extensions: HashMap<String, usize>,
1644}
1645
1646id_type!(OrgId);
1647#[derive(FromRow)]
1648pub struct Org {
1649 pub id: OrgId,
1650 pub name: String,
1651 pub slug: String,
1652}
1653
1654id_type!(ChannelId);
1655#[derive(Clone, Debug, FromRow, Serialize)]
1656pub struct Channel {
1657 pub id: ChannelId,
1658 pub name: String,
1659 pub owner_id: i32,
1660 pub owner_is_user: bool,
1661}
1662
1663id_type!(MessageId);
1664#[derive(Clone, Debug, FromRow)]
1665pub struct ChannelMessage {
1666 pub id: MessageId,
1667 pub channel_id: ChannelId,
1668 pub sender_id: UserId,
1669 pub body: String,
1670 pub sent_at: OffsetDateTime,
1671 pub nonce: Uuid,
1672}
1673
1674#[derive(Clone, Debug, PartialEq, Eq)]
1675pub enum Contact {
1676 Accepted {
1677 user_id: UserId,
1678 should_notify: bool,
1679 },
1680 Outgoing {
1681 user_id: UserId,
1682 },
1683 Incoming {
1684 user_id: UserId,
1685 should_notify: bool,
1686 },
1687}
1688
1689impl Contact {
1690 pub fn user_id(&self) -> UserId {
1691 match self {
1692 Contact::Accepted { user_id, .. } => *user_id,
1693 Contact::Outgoing { user_id } => *user_id,
1694 Contact::Incoming { user_id, .. } => *user_id,
1695 }
1696 }
1697}
1698
1699#[derive(Clone, Debug, PartialEq, Eq, PartialOrd, Ord)]
1700pub struct IncomingContactRequest {
1701 pub requester_id: UserId,
1702 pub should_notify: bool,
1703}
1704
1705#[derive(Clone, Deserialize)]
1706pub struct Signup {
1707 pub email_address: String,
1708 pub platform_mac: bool,
1709 pub platform_windows: bool,
1710 pub platform_linux: bool,
1711 pub editor_features: Vec<String>,
1712 pub programming_languages: Vec<String>,
1713 pub device_id: Option<String>,
1714}
1715
1716#[derive(Clone, Debug, PartialEq, Deserialize, Serialize, FromRow)]
1717pub struct WaitlistSummary {
1718 #[sqlx(default)]
1719 pub count: i64,
1720 #[sqlx(default)]
1721 pub linux_count: i64,
1722 #[sqlx(default)]
1723 pub mac_count: i64,
1724 #[sqlx(default)]
1725 pub windows_count: i64,
1726}
1727
1728#[derive(FromRow, PartialEq, Debug, Serialize, Deserialize)]
1729pub struct Invite {
1730 pub email_address: String,
1731 pub email_confirmation_code: String,
1732}
1733
1734#[derive(Debug, Serialize, Deserialize)]
1735pub struct NewUserParams {
1736 pub github_login: String,
1737 pub github_user_id: i32,
1738 pub invite_count: i32,
1739}
1740
1741#[derive(Debug)]
1742pub struct NewUserResult {
1743 pub user_id: UserId,
1744 pub metrics_id: String,
1745 pub inviting_user_id: Option<UserId>,
1746 pub signup_device_id: Option<String>,
1747}
1748
1749fn random_invite_code() -> String {
1750 nanoid::nanoid!(16)
1751}
1752
1753fn random_email_confirmation_code() -> String {
1754 nanoid::nanoid!(64)
1755}
1756
1757#[cfg(test)]
1758pub use test::*;
1759
1760#[cfg(test)]
1761mod test {
1762 use super::*;
1763 use anyhow::anyhow;
1764 use collections::BTreeMap;
1765 use gpui::executor::Background;
1766 use lazy_static::lazy_static;
1767 use parking_lot::Mutex;
1768 use rand::prelude::*;
1769 use sqlx::{
1770 migrate::{MigrateDatabase, Migrator},
1771 Postgres,
1772 };
1773 use std::{path::Path, sync::Arc};
1774 use util::post_inc;
1775
1776 pub struct FakeDb {
1777 background: Arc<Background>,
1778 pub users: Mutex<BTreeMap<UserId, User>>,
1779 pub projects: Mutex<BTreeMap<ProjectId, Project>>,
1780 pub worktree_extensions: Mutex<BTreeMap<(ProjectId, u64, String), u32>>,
1781 pub orgs: Mutex<BTreeMap<OrgId, Org>>,
1782 pub org_memberships: Mutex<BTreeMap<(OrgId, UserId), bool>>,
1783 pub channels: Mutex<BTreeMap<ChannelId, Channel>>,
1784 pub channel_memberships: Mutex<BTreeMap<(ChannelId, UserId), bool>>,
1785 pub channel_messages: Mutex<BTreeMap<MessageId, ChannelMessage>>,
1786 pub contacts: Mutex<Vec<FakeContact>>,
1787 next_channel_message_id: Mutex<i32>,
1788 next_user_id: Mutex<i32>,
1789 next_org_id: Mutex<i32>,
1790 next_channel_id: Mutex<i32>,
1791 next_project_id: Mutex<i32>,
1792 }
1793
1794 #[derive(Debug)]
1795 pub struct FakeContact {
1796 pub requester_id: UserId,
1797 pub responder_id: UserId,
1798 pub accepted: bool,
1799 pub should_notify: bool,
1800 }
1801
1802 impl FakeDb {
1803 pub fn new(background: Arc<Background>) -> Self {
1804 Self {
1805 background,
1806 users: Default::default(),
1807 next_user_id: Mutex::new(0),
1808 projects: Default::default(),
1809 worktree_extensions: Default::default(),
1810 next_project_id: Mutex::new(1),
1811 orgs: Default::default(),
1812 next_org_id: Mutex::new(1),
1813 org_memberships: Default::default(),
1814 channels: Default::default(),
1815 next_channel_id: Mutex::new(1),
1816 channel_memberships: Default::default(),
1817 channel_messages: Default::default(),
1818 next_channel_message_id: Mutex::new(1),
1819 contacts: Default::default(),
1820 }
1821 }
1822 }
1823
1824 #[async_trait]
1825 impl Db for FakeDb {
1826 async fn create_user(
1827 &self,
1828 email_address: &str,
1829 admin: bool,
1830 params: NewUserParams,
1831 ) -> Result<NewUserResult> {
1832 self.background.simulate_random_delay().await;
1833
1834 let mut users = self.users.lock();
1835 let user_id = if let Some(user) = users
1836 .values()
1837 .find(|user| user.github_login == params.github_login)
1838 {
1839 user.id
1840 } else {
1841 let id = post_inc(&mut *self.next_user_id.lock());
1842 let user_id = UserId(id);
1843 users.insert(
1844 user_id,
1845 User {
1846 id: user_id,
1847 github_login: params.github_login,
1848 github_user_id: Some(params.github_user_id),
1849 email_address: Some(email_address.to_string()),
1850 admin,
1851 invite_code: None,
1852 invite_count: 0,
1853 connected_once: false,
1854 },
1855 );
1856 user_id
1857 };
1858 Ok(NewUserResult {
1859 user_id,
1860 metrics_id: "the-metrics-id".to_string(),
1861 inviting_user_id: None,
1862 signup_device_id: None,
1863 })
1864 }
1865
1866 async fn get_all_users(&self, _page: u32, _limit: u32) -> Result<Vec<User>> {
1867 unimplemented!()
1868 }
1869
1870 async fn fuzzy_search_users(&self, _: &str, _: u32) -> Result<Vec<User>> {
1871 unimplemented!()
1872 }
1873
1874 async fn get_user_by_id(&self, id: UserId) -> Result<Option<User>> {
1875 self.background.simulate_random_delay().await;
1876 Ok(self.get_users_by_ids(vec![id]).await?.into_iter().next())
1877 }
1878
1879 async fn get_user_metrics_id(&self, _id: UserId) -> Result<String> {
1880 Ok("the-metrics-id".to_string())
1881 }
1882
1883 async fn get_users_by_ids(&self, ids: Vec<UserId>) -> Result<Vec<User>> {
1884 self.background.simulate_random_delay().await;
1885 let users = self.users.lock();
1886 Ok(ids.iter().filter_map(|id| users.get(id).cloned()).collect())
1887 }
1888
1889 async fn get_users_with_no_invites(&self, _: bool) -> Result<Vec<User>> {
1890 unimplemented!()
1891 }
1892
1893 async fn get_user_by_github_account(
1894 &self,
1895 github_login: &str,
1896 github_user_id: Option<i32>,
1897 ) -> Result<Option<User>> {
1898 self.background.simulate_random_delay().await;
1899 if let Some(github_user_id) = github_user_id {
1900 for user in self.users.lock().values_mut() {
1901 if user.github_user_id == Some(github_user_id) {
1902 user.github_login = github_login.into();
1903 return Ok(Some(user.clone()));
1904 }
1905 if user.github_login == github_login {
1906 user.github_user_id = Some(github_user_id);
1907 return Ok(Some(user.clone()));
1908 }
1909 }
1910 Ok(None)
1911 } else {
1912 Ok(self
1913 .users
1914 .lock()
1915 .values()
1916 .find(|user| user.github_login == github_login)
1917 .cloned())
1918 }
1919 }
1920
1921 async fn set_user_is_admin(&self, _id: UserId, _is_admin: bool) -> Result<()> {
1922 unimplemented!()
1923 }
1924
1925 async fn set_user_connected_once(&self, id: UserId, connected_once: bool) -> Result<()> {
1926 self.background.simulate_random_delay().await;
1927 let mut users = self.users.lock();
1928 let mut user = users
1929 .get_mut(&id)
1930 .ok_or_else(|| anyhow!("user not found"))?;
1931 user.connected_once = connected_once;
1932 Ok(())
1933 }
1934
1935 async fn destroy_user(&self, _id: UserId) -> Result<()> {
1936 unimplemented!()
1937 }
1938
1939 // signups
1940
1941 async fn create_signup(&self, _signup: Signup) -> Result<()> {
1942 unimplemented!()
1943 }
1944
1945 async fn get_waitlist_summary(&self) -> Result<WaitlistSummary> {
1946 unimplemented!()
1947 }
1948
1949 async fn get_unsent_invites(&self, _count: usize) -> Result<Vec<Invite>> {
1950 unimplemented!()
1951 }
1952
1953 async fn record_sent_invites(&self, _invites: &[Invite]) -> Result<()> {
1954 unimplemented!()
1955 }
1956
1957 async fn create_user_from_invite(
1958 &self,
1959 _invite: &Invite,
1960 _user: NewUserParams,
1961 ) -> Result<NewUserResult> {
1962 unimplemented!()
1963 }
1964
1965 // invite codes
1966
1967 async fn set_invite_count_for_user(&self, _id: UserId, _count: u32) -> Result<()> {
1968 unimplemented!()
1969 }
1970
1971 async fn get_invite_code_for_user(&self, _id: UserId) -> Result<Option<(String, u32)>> {
1972 self.background.simulate_random_delay().await;
1973 Ok(None)
1974 }
1975
1976 async fn get_user_for_invite_code(&self, _code: &str) -> Result<User> {
1977 unimplemented!()
1978 }
1979
1980 async fn create_invite_from_code(
1981 &self,
1982 _code: &str,
1983 _email_address: &str,
1984 _device_id: Option<&str>,
1985 ) -> Result<Invite> {
1986 unimplemented!()
1987 }
1988
1989 // projects
1990
1991 async fn register_project(&self, host_user_id: UserId) -> Result<ProjectId> {
1992 self.background.simulate_random_delay().await;
1993 if !self.users.lock().contains_key(&host_user_id) {
1994 Err(anyhow!("no such user"))?;
1995 }
1996
1997 let project_id = ProjectId(post_inc(&mut *self.next_project_id.lock()));
1998 self.projects.lock().insert(
1999 project_id,
2000 Project {
2001 id: project_id,
2002 host_user_id,
2003 unregistered: false,
2004 },
2005 );
2006 Ok(project_id)
2007 }
2008
2009 async fn unregister_project(&self, project_id: ProjectId) -> Result<()> {
2010 self.background.simulate_random_delay().await;
2011 self.projects
2012 .lock()
2013 .get_mut(&project_id)
2014 .ok_or_else(|| anyhow!("no such project"))?
2015 .unregistered = true;
2016 Ok(())
2017 }
2018
2019 async fn update_worktree_extensions(
2020 &self,
2021 project_id: ProjectId,
2022 worktree_id: u64,
2023 extensions: HashMap<String, u32>,
2024 ) -> Result<()> {
2025 self.background.simulate_random_delay().await;
2026 if !self.projects.lock().contains_key(&project_id) {
2027 Err(anyhow!("no such project"))?;
2028 }
2029
2030 for (extension, count) in extensions {
2031 self.worktree_extensions
2032 .lock()
2033 .insert((project_id, worktree_id, extension), count);
2034 }
2035
2036 Ok(())
2037 }
2038
2039 async fn get_project_extensions(
2040 &self,
2041 _project_id: ProjectId,
2042 ) -> Result<HashMap<u64, HashMap<String, usize>>> {
2043 unimplemented!()
2044 }
2045
2046 async fn record_user_activity(
2047 &self,
2048 _time_period: Range<OffsetDateTime>,
2049 _active_projects: &[(UserId, ProjectId)],
2050 ) -> Result<()> {
2051 unimplemented!()
2052 }
2053
2054 async fn get_active_user_count(
2055 &self,
2056 _time_period: Range<OffsetDateTime>,
2057 _min_duration: Duration,
2058 _only_collaborative: bool,
2059 ) -> Result<usize> {
2060 unimplemented!()
2061 }
2062
2063 async fn get_top_users_activity_summary(
2064 &self,
2065 _time_period: Range<OffsetDateTime>,
2066 _limit: usize,
2067 ) -> Result<Vec<UserActivitySummary>> {
2068 unimplemented!()
2069 }
2070
2071 async fn get_user_activity_timeline(
2072 &self,
2073 _time_period: Range<OffsetDateTime>,
2074 _user_id: UserId,
2075 ) -> Result<Vec<UserActivityPeriod>> {
2076 unimplemented!()
2077 }
2078
2079 // contacts
2080
2081 async fn get_contacts(&self, id: UserId) -> Result<Vec<Contact>> {
2082 self.background.simulate_random_delay().await;
2083 let mut contacts = vec![Contact::Accepted {
2084 user_id: id,
2085 should_notify: false,
2086 }];
2087
2088 for contact in self.contacts.lock().iter() {
2089 if contact.requester_id == id {
2090 if contact.accepted {
2091 contacts.push(Contact::Accepted {
2092 user_id: contact.responder_id,
2093 should_notify: contact.should_notify,
2094 });
2095 } else {
2096 contacts.push(Contact::Outgoing {
2097 user_id: contact.responder_id,
2098 });
2099 }
2100 } else if contact.responder_id == id {
2101 if contact.accepted {
2102 contacts.push(Contact::Accepted {
2103 user_id: contact.requester_id,
2104 should_notify: false,
2105 });
2106 } else {
2107 contacts.push(Contact::Incoming {
2108 user_id: contact.requester_id,
2109 should_notify: contact.should_notify,
2110 });
2111 }
2112 }
2113 }
2114
2115 contacts.sort_unstable_by_key(|contact| contact.user_id());
2116 Ok(contacts)
2117 }
2118
2119 async fn has_contact(&self, user_id_a: UserId, user_id_b: UserId) -> Result<bool> {
2120 self.background.simulate_random_delay().await;
2121 Ok(self.contacts.lock().iter().any(|contact| {
2122 contact.accepted
2123 && ((contact.requester_id == user_id_a && contact.responder_id == user_id_b)
2124 || (contact.requester_id == user_id_b && contact.responder_id == user_id_a))
2125 }))
2126 }
2127
2128 async fn send_contact_request(
2129 &self,
2130 requester_id: UserId,
2131 responder_id: UserId,
2132 ) -> Result<()> {
2133 self.background.simulate_random_delay().await;
2134 let mut contacts = self.contacts.lock();
2135 for contact in contacts.iter_mut() {
2136 if contact.requester_id == requester_id && contact.responder_id == responder_id {
2137 if contact.accepted {
2138 Err(anyhow!("contact already exists"))?;
2139 } else {
2140 Err(anyhow!("contact already requested"))?;
2141 }
2142 }
2143 if contact.responder_id == requester_id && contact.requester_id == responder_id {
2144 if contact.accepted {
2145 Err(anyhow!("contact already exists"))?;
2146 } else {
2147 contact.accepted = true;
2148 contact.should_notify = false;
2149 return Ok(());
2150 }
2151 }
2152 }
2153 contacts.push(FakeContact {
2154 requester_id,
2155 responder_id,
2156 accepted: false,
2157 should_notify: true,
2158 });
2159 Ok(())
2160 }
2161
2162 async fn remove_contact(&self, requester_id: UserId, responder_id: UserId) -> Result<()> {
2163 self.background.simulate_random_delay().await;
2164 self.contacts.lock().retain(|contact| {
2165 !(contact.requester_id == requester_id && contact.responder_id == responder_id)
2166 });
2167 Ok(())
2168 }
2169
2170 async fn dismiss_contact_notification(
2171 &self,
2172 user_id: UserId,
2173 contact_user_id: UserId,
2174 ) -> Result<()> {
2175 self.background.simulate_random_delay().await;
2176 let mut contacts = self.contacts.lock();
2177 for contact in contacts.iter_mut() {
2178 if contact.requester_id == contact_user_id
2179 && contact.responder_id == user_id
2180 && !contact.accepted
2181 {
2182 contact.should_notify = false;
2183 return Ok(());
2184 }
2185 if contact.requester_id == user_id
2186 && contact.responder_id == contact_user_id
2187 && contact.accepted
2188 {
2189 contact.should_notify = false;
2190 return Ok(());
2191 }
2192 }
2193 Err(anyhow!("no such notification"))?
2194 }
2195
2196 async fn respond_to_contact_request(
2197 &self,
2198 responder_id: UserId,
2199 requester_id: UserId,
2200 accept: bool,
2201 ) -> Result<()> {
2202 self.background.simulate_random_delay().await;
2203 let mut contacts = self.contacts.lock();
2204 for (ix, contact) in contacts.iter_mut().enumerate() {
2205 if contact.requester_id == requester_id && contact.responder_id == responder_id {
2206 if contact.accepted {
2207 Err(anyhow!("contact already confirmed"))?;
2208 }
2209 if accept {
2210 contact.accepted = true;
2211 contact.should_notify = true;
2212 } else {
2213 contacts.remove(ix);
2214 }
2215 return Ok(());
2216 }
2217 }
2218 Err(anyhow!("no such contact request"))?
2219 }
2220
2221 async fn create_access_token_hash(
2222 &self,
2223 _user_id: UserId,
2224 _access_token_hash: &str,
2225 _max_access_token_count: usize,
2226 ) -> Result<()> {
2227 unimplemented!()
2228 }
2229
2230 async fn get_access_token_hashes(&self, _user_id: UserId) -> Result<Vec<String>> {
2231 unimplemented!()
2232 }
2233
2234 async fn find_org_by_slug(&self, _slug: &str) -> Result<Option<Org>> {
2235 unimplemented!()
2236 }
2237
2238 async fn create_org(&self, name: &str, slug: &str) -> Result<OrgId> {
2239 self.background.simulate_random_delay().await;
2240 let mut orgs = self.orgs.lock();
2241 if orgs.values().any(|org| org.slug == slug) {
2242 Err(anyhow!("org already exists"))?
2243 } else {
2244 let org_id = OrgId(post_inc(&mut *self.next_org_id.lock()));
2245 orgs.insert(
2246 org_id,
2247 Org {
2248 id: org_id,
2249 name: name.to_string(),
2250 slug: slug.to_string(),
2251 },
2252 );
2253 Ok(org_id)
2254 }
2255 }
2256
2257 async fn add_org_member(
2258 &self,
2259 org_id: OrgId,
2260 user_id: UserId,
2261 is_admin: bool,
2262 ) -> Result<()> {
2263 self.background.simulate_random_delay().await;
2264 if !self.orgs.lock().contains_key(&org_id) {
2265 Err(anyhow!("org does not exist"))?;
2266 }
2267 if !self.users.lock().contains_key(&user_id) {
2268 Err(anyhow!("user does not exist"))?;
2269 }
2270
2271 self.org_memberships
2272 .lock()
2273 .entry((org_id, user_id))
2274 .or_insert(is_admin);
2275 Ok(())
2276 }
2277
2278 async fn create_org_channel(&self, org_id: OrgId, name: &str) -> Result<ChannelId> {
2279 self.background.simulate_random_delay().await;
2280 if !self.orgs.lock().contains_key(&org_id) {
2281 Err(anyhow!("org does not exist"))?;
2282 }
2283
2284 let mut channels = self.channels.lock();
2285 let channel_id = ChannelId(post_inc(&mut *self.next_channel_id.lock()));
2286 channels.insert(
2287 channel_id,
2288 Channel {
2289 id: channel_id,
2290 name: name.to_string(),
2291 owner_id: org_id.0,
2292 owner_is_user: false,
2293 },
2294 );
2295 Ok(channel_id)
2296 }
2297
2298 async fn get_org_channels(&self, org_id: OrgId) -> Result<Vec<Channel>> {
2299 self.background.simulate_random_delay().await;
2300 Ok(self
2301 .channels
2302 .lock()
2303 .values()
2304 .filter(|channel| !channel.owner_is_user && channel.owner_id == org_id.0)
2305 .cloned()
2306 .collect())
2307 }
2308
2309 async fn get_accessible_channels(&self, user_id: UserId) -> Result<Vec<Channel>> {
2310 self.background.simulate_random_delay().await;
2311 let channels = self.channels.lock();
2312 let memberships = self.channel_memberships.lock();
2313 Ok(channels
2314 .values()
2315 .filter(|channel| memberships.contains_key(&(channel.id, user_id)))
2316 .cloned()
2317 .collect())
2318 }
2319
2320 async fn can_user_access_channel(
2321 &self,
2322 user_id: UserId,
2323 channel_id: ChannelId,
2324 ) -> Result<bool> {
2325 self.background.simulate_random_delay().await;
2326 Ok(self
2327 .channel_memberships
2328 .lock()
2329 .contains_key(&(channel_id, user_id)))
2330 }
2331
2332 async fn add_channel_member(
2333 &self,
2334 channel_id: ChannelId,
2335 user_id: UserId,
2336 is_admin: bool,
2337 ) -> Result<()> {
2338 self.background.simulate_random_delay().await;
2339 if !self.channels.lock().contains_key(&channel_id) {
2340 Err(anyhow!("channel does not exist"))?;
2341 }
2342 if !self.users.lock().contains_key(&user_id) {
2343 Err(anyhow!("user does not exist"))?;
2344 }
2345
2346 self.channel_memberships
2347 .lock()
2348 .entry((channel_id, user_id))
2349 .or_insert(is_admin);
2350 Ok(())
2351 }
2352
2353 async fn create_channel_message(
2354 &self,
2355 channel_id: ChannelId,
2356 sender_id: UserId,
2357 body: &str,
2358 timestamp: OffsetDateTime,
2359 nonce: u128,
2360 ) -> Result<MessageId> {
2361 self.background.simulate_random_delay().await;
2362 if !self.channels.lock().contains_key(&channel_id) {
2363 Err(anyhow!("channel does not exist"))?;
2364 }
2365 if !self.users.lock().contains_key(&sender_id) {
2366 Err(anyhow!("user does not exist"))?;
2367 }
2368
2369 let mut messages = self.channel_messages.lock();
2370 if let Some(message) = messages
2371 .values()
2372 .find(|message| message.nonce.as_u128() == nonce)
2373 {
2374 Ok(message.id)
2375 } else {
2376 let message_id = MessageId(post_inc(&mut *self.next_channel_message_id.lock()));
2377 messages.insert(
2378 message_id,
2379 ChannelMessage {
2380 id: message_id,
2381 channel_id,
2382 sender_id,
2383 body: body.to_string(),
2384 sent_at: timestamp,
2385 nonce: Uuid::from_u128(nonce),
2386 },
2387 );
2388 Ok(message_id)
2389 }
2390 }
2391
2392 async fn get_channel_messages(
2393 &self,
2394 channel_id: ChannelId,
2395 count: usize,
2396 before_id: Option<MessageId>,
2397 ) -> Result<Vec<ChannelMessage>> {
2398 self.background.simulate_random_delay().await;
2399 let mut messages = self
2400 .channel_messages
2401 .lock()
2402 .values()
2403 .rev()
2404 .filter(|message| {
2405 message.channel_id == channel_id
2406 && message.id < before_id.unwrap_or(MessageId::MAX)
2407 })
2408 .take(count)
2409 .cloned()
2410 .collect::<Vec<_>>();
2411 messages.sort_unstable_by_key(|message| message.id);
2412 Ok(messages)
2413 }
2414
2415 async fn teardown(&self, _: &str) {}
2416
2417 #[cfg(test)]
2418 fn as_fake(&self) -> Option<&FakeDb> {
2419 Some(self)
2420 }
2421 }
2422
2423 pub struct TestDb {
2424 pub db: Option<Arc<dyn Db>>,
2425 pub url: String,
2426 }
2427
2428 impl TestDb {
2429 #[allow(clippy::await_holding_lock)]
2430 pub async fn postgres() -> Self {
2431 lazy_static! {
2432 static ref LOCK: Mutex<()> = Mutex::new(());
2433 }
2434
2435 let _guard = LOCK.lock();
2436 let mut rng = StdRng::from_entropy();
2437 let name = format!("zed-test-{}", rng.gen::<u128>());
2438 let url = format!("postgres://postgres@localhost/{}", name);
2439 let migrations_path = Path::new(concat!(env!("CARGO_MANIFEST_DIR"), "/migrations"));
2440 Postgres::create_database(&url)
2441 .await
2442 .expect("failed to create test db");
2443 let db = PostgresDb::new(&url, 5).await.unwrap();
2444 let migrator = Migrator::new(migrations_path).await.unwrap();
2445 migrator.run(&db.pool).await.unwrap();
2446 Self {
2447 db: Some(Arc::new(db)),
2448 url,
2449 }
2450 }
2451
2452 pub fn fake(background: Arc<Background>) -> Self {
2453 Self {
2454 db: Some(Arc::new(FakeDb::new(background))),
2455 url: Default::default(),
2456 }
2457 }
2458
2459 pub fn db(&self) -> &Arc<dyn Db> {
2460 self.db.as_ref().unwrap()
2461 }
2462 }
2463
2464 impl Drop for TestDb {
2465 fn drop(&mut self) {
2466 if let Some(db) = self.db.take() {
2467 futures::executor::block_on(db.teardown(&self.url));
2468 }
2469 }
2470 }
2471}