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::new();
1102 while let Some(row) = rows.next().await {
1103 let (user_id_a, user_id_b, a_to_b, accepted, should_notify) = row?;
1104
1105 if user_id_a == user_id {
1106 if accepted {
1107 contacts.push(Contact::Accepted {
1108 user_id: user_id_b,
1109 should_notify: should_notify && a_to_b,
1110 });
1111 } else if a_to_b {
1112 contacts.push(Contact::Outgoing { user_id: user_id_b })
1113 } else {
1114 contacts.push(Contact::Incoming {
1115 user_id: user_id_b,
1116 should_notify,
1117 });
1118 }
1119 } else if accepted {
1120 contacts.push(Contact::Accepted {
1121 user_id: user_id_a,
1122 should_notify: should_notify && !a_to_b,
1123 });
1124 } else if a_to_b {
1125 contacts.push(Contact::Incoming {
1126 user_id: user_id_a,
1127 should_notify,
1128 });
1129 } else {
1130 contacts.push(Contact::Outgoing { user_id: user_id_a });
1131 }
1132 }
1133
1134 contacts.sort_unstable_by_key(|contact| contact.user_id());
1135
1136 Ok(contacts)
1137 }
1138
1139 async fn has_contact(&self, user_id_1: UserId, user_id_2: UserId) -> Result<bool> {
1140 let (id_a, id_b) = if user_id_1 < user_id_2 {
1141 (user_id_1, user_id_2)
1142 } else {
1143 (user_id_2, user_id_1)
1144 };
1145
1146 let query = "
1147 SELECT 1 FROM contacts
1148 WHERE user_id_a = $1 AND user_id_b = $2 AND accepted = 't'
1149 LIMIT 1
1150 ";
1151 Ok(sqlx::query_scalar::<_, i32>(query)
1152 .bind(id_a.0)
1153 .bind(id_b.0)
1154 .fetch_optional(&self.pool)
1155 .await?
1156 .is_some())
1157 }
1158
1159 async fn send_contact_request(&self, sender_id: UserId, receiver_id: UserId) -> Result<()> {
1160 let (id_a, id_b, a_to_b) = if sender_id < receiver_id {
1161 (sender_id, receiver_id, true)
1162 } else {
1163 (receiver_id, sender_id, false)
1164 };
1165 let query = "
1166 INSERT into contacts (user_id_a, user_id_b, a_to_b, accepted, should_notify)
1167 VALUES ($1, $2, $3, 'f', 't')
1168 ON CONFLICT (user_id_a, user_id_b) DO UPDATE
1169 SET
1170 accepted = 't',
1171 should_notify = 'f'
1172 WHERE
1173 NOT contacts.accepted AND
1174 ((contacts.a_to_b = excluded.a_to_b AND contacts.user_id_a = excluded.user_id_b) OR
1175 (contacts.a_to_b != excluded.a_to_b AND contacts.user_id_a = excluded.user_id_a));
1176 ";
1177 let result = sqlx::query(query)
1178 .bind(id_a.0)
1179 .bind(id_b.0)
1180 .bind(a_to_b)
1181 .execute(&self.pool)
1182 .await?;
1183
1184 if result.rows_affected() == 1 {
1185 Ok(())
1186 } else {
1187 Err(anyhow!("contact already requested"))?
1188 }
1189 }
1190
1191 async fn remove_contact(&self, requester_id: UserId, responder_id: UserId) -> Result<()> {
1192 let (id_a, id_b) = if responder_id < requester_id {
1193 (responder_id, requester_id)
1194 } else {
1195 (requester_id, responder_id)
1196 };
1197 let query = "
1198 DELETE FROM contacts
1199 WHERE user_id_a = $1 AND user_id_b = $2;
1200 ";
1201 let result = sqlx::query(query)
1202 .bind(id_a.0)
1203 .bind(id_b.0)
1204 .execute(&self.pool)
1205 .await?;
1206
1207 if result.rows_affected() == 1 {
1208 Ok(())
1209 } else {
1210 Err(anyhow!("no such contact"))?
1211 }
1212 }
1213
1214 async fn dismiss_contact_notification(
1215 &self,
1216 user_id: UserId,
1217 contact_user_id: UserId,
1218 ) -> Result<()> {
1219 let (id_a, id_b, a_to_b) = if user_id < contact_user_id {
1220 (user_id, contact_user_id, true)
1221 } else {
1222 (contact_user_id, user_id, false)
1223 };
1224
1225 let query = "
1226 UPDATE contacts
1227 SET should_notify = 'f'
1228 WHERE
1229 user_id_a = $1 AND user_id_b = $2 AND
1230 (
1231 (a_to_b = $3 AND accepted) OR
1232 (a_to_b != $3 AND NOT accepted)
1233 );
1234 ";
1235
1236 let result = sqlx::query(query)
1237 .bind(id_a.0)
1238 .bind(id_b.0)
1239 .bind(a_to_b)
1240 .execute(&self.pool)
1241 .await?;
1242
1243 if result.rows_affected() == 0 {
1244 Err(anyhow!("no such contact request"))?;
1245 }
1246
1247 Ok(())
1248 }
1249
1250 async fn respond_to_contact_request(
1251 &self,
1252 responder_id: UserId,
1253 requester_id: UserId,
1254 accept: bool,
1255 ) -> Result<()> {
1256 let (id_a, id_b, a_to_b) = if responder_id < requester_id {
1257 (responder_id, requester_id, false)
1258 } else {
1259 (requester_id, responder_id, true)
1260 };
1261 let result = if accept {
1262 let query = "
1263 UPDATE contacts
1264 SET accepted = 't', should_notify = 't'
1265 WHERE user_id_a = $1 AND user_id_b = $2 AND a_to_b = $3;
1266 ";
1267 sqlx::query(query)
1268 .bind(id_a.0)
1269 .bind(id_b.0)
1270 .bind(a_to_b)
1271 .execute(&self.pool)
1272 .await?
1273 } else {
1274 let query = "
1275 DELETE FROM contacts
1276 WHERE user_id_a = $1 AND user_id_b = $2 AND a_to_b = $3 AND NOT accepted;
1277 ";
1278 sqlx::query(query)
1279 .bind(id_a.0)
1280 .bind(id_b.0)
1281 .bind(a_to_b)
1282 .execute(&self.pool)
1283 .await?
1284 };
1285 if result.rows_affected() == 1 {
1286 Ok(())
1287 } else {
1288 Err(anyhow!("no such contact request"))?
1289 }
1290 }
1291
1292 // access tokens
1293
1294 async fn create_access_token_hash(
1295 &self,
1296 user_id: UserId,
1297 access_token_hash: &str,
1298 max_access_token_count: usize,
1299 ) -> Result<()> {
1300 let insert_query = "
1301 INSERT INTO access_tokens (user_id, hash)
1302 VALUES ($1, $2);
1303 ";
1304 let cleanup_query = "
1305 DELETE FROM access_tokens
1306 WHERE id IN (
1307 SELECT id from access_tokens
1308 WHERE user_id = $1
1309 ORDER BY id DESC
1310 OFFSET $3
1311 )
1312 ";
1313
1314 let mut tx = self.pool.begin().await?;
1315 sqlx::query(insert_query)
1316 .bind(user_id.0)
1317 .bind(access_token_hash)
1318 .execute(&mut tx)
1319 .await?;
1320 sqlx::query(cleanup_query)
1321 .bind(user_id.0)
1322 .bind(access_token_hash)
1323 .bind(max_access_token_count as i32)
1324 .execute(&mut tx)
1325 .await?;
1326 Ok(tx.commit().await?)
1327 }
1328
1329 async fn get_access_token_hashes(&self, user_id: UserId) -> Result<Vec<String>> {
1330 let query = "
1331 SELECT hash
1332 FROM access_tokens
1333 WHERE user_id = $1
1334 ORDER BY id DESC
1335 ";
1336 Ok(sqlx::query_scalar(query)
1337 .bind(user_id.0)
1338 .fetch_all(&self.pool)
1339 .await?)
1340 }
1341
1342 // orgs
1343
1344 #[allow(unused)] // Help rust-analyzer
1345 #[cfg(any(test, feature = "seed-support"))]
1346 async fn find_org_by_slug(&self, slug: &str) -> Result<Option<Org>> {
1347 let query = "
1348 SELECT *
1349 FROM orgs
1350 WHERE slug = $1
1351 ";
1352 Ok(sqlx::query_as(query)
1353 .bind(slug)
1354 .fetch_optional(&self.pool)
1355 .await?)
1356 }
1357
1358 #[cfg(any(test, feature = "seed-support"))]
1359 async fn create_org(&self, name: &str, slug: &str) -> Result<OrgId> {
1360 let query = "
1361 INSERT INTO orgs (name, slug)
1362 VALUES ($1, $2)
1363 RETURNING id
1364 ";
1365 Ok(sqlx::query_scalar(query)
1366 .bind(name)
1367 .bind(slug)
1368 .fetch_one(&self.pool)
1369 .await
1370 .map(OrgId)?)
1371 }
1372
1373 #[cfg(any(test, feature = "seed-support"))]
1374 async fn add_org_member(&self, org_id: OrgId, user_id: UserId, is_admin: bool) -> Result<()> {
1375 let query = "
1376 INSERT INTO org_memberships (org_id, user_id, admin)
1377 VALUES ($1, $2, $3)
1378 ON CONFLICT DO NOTHING
1379 ";
1380 Ok(sqlx::query(query)
1381 .bind(org_id.0)
1382 .bind(user_id.0)
1383 .bind(is_admin)
1384 .execute(&self.pool)
1385 .await
1386 .map(drop)?)
1387 }
1388
1389 // channels
1390
1391 #[cfg(any(test, feature = "seed-support"))]
1392 async fn create_org_channel(&self, org_id: OrgId, name: &str) -> Result<ChannelId> {
1393 let query = "
1394 INSERT INTO channels (owner_id, owner_is_user, name)
1395 VALUES ($1, false, $2)
1396 RETURNING id
1397 ";
1398 Ok(sqlx::query_scalar(query)
1399 .bind(org_id.0)
1400 .bind(name)
1401 .fetch_one(&self.pool)
1402 .await
1403 .map(ChannelId)?)
1404 }
1405
1406 #[allow(unused)] // Help rust-analyzer
1407 #[cfg(any(test, feature = "seed-support"))]
1408 async fn get_org_channels(&self, org_id: OrgId) -> Result<Vec<Channel>> {
1409 let query = "
1410 SELECT *
1411 FROM channels
1412 WHERE
1413 channels.owner_is_user = false AND
1414 channels.owner_id = $1
1415 ";
1416 Ok(sqlx::query_as(query)
1417 .bind(org_id.0)
1418 .fetch_all(&self.pool)
1419 .await?)
1420 }
1421
1422 async fn get_accessible_channels(&self, user_id: UserId) -> Result<Vec<Channel>> {
1423 let query = "
1424 SELECT
1425 channels.*
1426 FROM
1427 channel_memberships, channels
1428 WHERE
1429 channel_memberships.user_id = $1 AND
1430 channel_memberships.channel_id = channels.id
1431 ";
1432 Ok(sqlx::query_as(query)
1433 .bind(user_id.0)
1434 .fetch_all(&self.pool)
1435 .await?)
1436 }
1437
1438 async fn can_user_access_channel(
1439 &self,
1440 user_id: UserId,
1441 channel_id: ChannelId,
1442 ) -> Result<bool> {
1443 let query = "
1444 SELECT id
1445 FROM channel_memberships
1446 WHERE user_id = $1 AND channel_id = $2
1447 LIMIT 1
1448 ";
1449 Ok(sqlx::query_scalar::<_, i32>(query)
1450 .bind(user_id.0)
1451 .bind(channel_id.0)
1452 .fetch_optional(&self.pool)
1453 .await
1454 .map(|e| e.is_some())?)
1455 }
1456
1457 #[cfg(any(test, feature = "seed-support"))]
1458 async fn add_channel_member(
1459 &self,
1460 channel_id: ChannelId,
1461 user_id: UserId,
1462 is_admin: bool,
1463 ) -> Result<()> {
1464 let query = "
1465 INSERT INTO channel_memberships (channel_id, user_id, admin)
1466 VALUES ($1, $2, $3)
1467 ON CONFLICT DO NOTHING
1468 ";
1469 Ok(sqlx::query(query)
1470 .bind(channel_id.0)
1471 .bind(user_id.0)
1472 .bind(is_admin)
1473 .execute(&self.pool)
1474 .await
1475 .map(drop)?)
1476 }
1477
1478 // messages
1479
1480 async fn create_channel_message(
1481 &self,
1482 channel_id: ChannelId,
1483 sender_id: UserId,
1484 body: &str,
1485 timestamp: OffsetDateTime,
1486 nonce: u128,
1487 ) -> Result<MessageId> {
1488 let query = "
1489 INSERT INTO channel_messages (channel_id, sender_id, body, sent_at, nonce)
1490 VALUES ($1, $2, $3, $4, $5)
1491 ON CONFLICT (nonce) DO UPDATE SET nonce = excluded.nonce
1492 RETURNING id
1493 ";
1494 Ok(sqlx::query_scalar(query)
1495 .bind(channel_id.0)
1496 .bind(sender_id.0)
1497 .bind(body)
1498 .bind(timestamp)
1499 .bind(Uuid::from_u128(nonce))
1500 .fetch_one(&self.pool)
1501 .await
1502 .map(MessageId)?)
1503 }
1504
1505 async fn get_channel_messages(
1506 &self,
1507 channel_id: ChannelId,
1508 count: usize,
1509 before_id: Option<MessageId>,
1510 ) -> Result<Vec<ChannelMessage>> {
1511 let query = r#"
1512 SELECT * FROM (
1513 SELECT
1514 id, channel_id, sender_id, body, sent_at AT TIME ZONE 'UTC' as sent_at, nonce
1515 FROM
1516 channel_messages
1517 WHERE
1518 channel_id = $1 AND
1519 id < $2
1520 ORDER BY id DESC
1521 LIMIT $3
1522 ) as recent_messages
1523 ORDER BY id ASC
1524 "#;
1525 Ok(sqlx::query_as(query)
1526 .bind(channel_id.0)
1527 .bind(before_id.unwrap_or(MessageId::MAX))
1528 .bind(count as i64)
1529 .fetch_all(&self.pool)
1530 .await?)
1531 }
1532
1533 #[cfg(test)]
1534 async fn teardown(&self, url: &str) {
1535 use util::ResultExt;
1536
1537 let query = "
1538 SELECT pg_terminate_backend(pg_stat_activity.pid)
1539 FROM pg_stat_activity
1540 WHERE pg_stat_activity.datname = current_database() AND pid <> pg_backend_pid();
1541 ";
1542 sqlx::query(query).execute(&self.pool).await.log_err();
1543 self.pool.close().await;
1544 <sqlx::Postgres as sqlx::migrate::MigrateDatabase>::drop_database(url)
1545 .await
1546 .log_err();
1547 }
1548
1549 #[cfg(test)]
1550 fn as_fake(&self) -> Option<&FakeDb> {
1551 None
1552 }
1553}
1554
1555macro_rules! id_type {
1556 ($name:ident) => {
1557 #[derive(
1558 Clone,
1559 Copy,
1560 Debug,
1561 Default,
1562 PartialEq,
1563 Eq,
1564 PartialOrd,
1565 Ord,
1566 Hash,
1567 sqlx::Type,
1568 Serialize,
1569 Deserialize,
1570 )]
1571 #[sqlx(transparent)]
1572 #[serde(transparent)]
1573 pub struct $name(pub i32);
1574
1575 impl $name {
1576 #[allow(unused)]
1577 pub const MAX: Self = Self(i32::MAX);
1578
1579 #[allow(unused)]
1580 pub fn from_proto(value: u64) -> Self {
1581 Self(value as i32)
1582 }
1583
1584 #[allow(unused)]
1585 pub fn to_proto(self) -> u64 {
1586 self.0 as u64
1587 }
1588 }
1589
1590 impl std::fmt::Display for $name {
1591 fn fmt(&self, f: &mut std::fmt::Formatter) -> std::fmt::Result {
1592 self.0.fmt(f)
1593 }
1594 }
1595 };
1596}
1597
1598id_type!(UserId);
1599#[derive(Clone, Debug, Default, FromRow, Serialize, PartialEq)]
1600pub struct User {
1601 pub id: UserId,
1602 pub github_login: String,
1603 pub github_user_id: Option<i32>,
1604 pub email_address: Option<String>,
1605 pub admin: bool,
1606 pub invite_code: Option<String>,
1607 pub invite_count: i32,
1608 pub connected_once: bool,
1609}
1610
1611id_type!(ProjectId);
1612#[derive(Clone, Debug, Default, FromRow, Serialize, PartialEq)]
1613pub struct Project {
1614 pub id: ProjectId,
1615 pub host_user_id: UserId,
1616 pub unregistered: bool,
1617}
1618
1619#[derive(Clone, Debug, PartialEq, Serialize)]
1620pub struct UserActivitySummary {
1621 pub id: UserId,
1622 pub github_login: String,
1623 pub project_activity: Vec<ProjectActivitySummary>,
1624}
1625
1626#[derive(Clone, Debug, PartialEq, Serialize)]
1627pub struct ProjectActivitySummary {
1628 pub id: ProjectId,
1629 pub duration: Duration,
1630 pub max_collaborators: usize,
1631}
1632
1633#[derive(Clone, Debug, PartialEq, Serialize)]
1634pub struct UserActivityPeriod {
1635 pub project_id: ProjectId,
1636 #[serde(with = "time::serde::iso8601")]
1637 pub start: OffsetDateTime,
1638 #[serde(with = "time::serde::iso8601")]
1639 pub end: OffsetDateTime,
1640 pub extensions: HashMap<String, usize>,
1641}
1642
1643id_type!(OrgId);
1644#[derive(FromRow)]
1645pub struct Org {
1646 pub id: OrgId,
1647 pub name: String,
1648 pub slug: String,
1649}
1650
1651id_type!(ChannelId);
1652#[derive(Clone, Debug, FromRow, Serialize)]
1653pub struct Channel {
1654 pub id: ChannelId,
1655 pub name: String,
1656 pub owner_id: i32,
1657 pub owner_is_user: bool,
1658}
1659
1660id_type!(MessageId);
1661#[derive(Clone, Debug, FromRow)]
1662pub struct ChannelMessage {
1663 pub id: MessageId,
1664 pub channel_id: ChannelId,
1665 pub sender_id: UserId,
1666 pub body: String,
1667 pub sent_at: OffsetDateTime,
1668 pub nonce: Uuid,
1669}
1670
1671#[derive(Clone, Debug, PartialEq, Eq)]
1672pub enum Contact {
1673 Accepted {
1674 user_id: UserId,
1675 should_notify: bool,
1676 },
1677 Outgoing {
1678 user_id: UserId,
1679 },
1680 Incoming {
1681 user_id: UserId,
1682 should_notify: bool,
1683 },
1684}
1685
1686impl Contact {
1687 pub fn user_id(&self) -> UserId {
1688 match self {
1689 Contact::Accepted { user_id, .. } => *user_id,
1690 Contact::Outgoing { user_id } => *user_id,
1691 Contact::Incoming { user_id, .. } => *user_id,
1692 }
1693 }
1694}
1695
1696#[derive(Clone, Debug, PartialEq, Eq, PartialOrd, Ord)]
1697pub struct IncomingContactRequest {
1698 pub requester_id: UserId,
1699 pub should_notify: bool,
1700}
1701
1702#[derive(Clone, Deserialize)]
1703pub struct Signup {
1704 pub email_address: String,
1705 pub platform_mac: bool,
1706 pub platform_windows: bool,
1707 pub platform_linux: bool,
1708 pub editor_features: Vec<String>,
1709 pub programming_languages: Vec<String>,
1710 pub device_id: Option<String>,
1711}
1712
1713#[derive(Clone, Debug, PartialEq, Deserialize, Serialize, FromRow)]
1714pub struct WaitlistSummary {
1715 #[sqlx(default)]
1716 pub count: i64,
1717 #[sqlx(default)]
1718 pub linux_count: i64,
1719 #[sqlx(default)]
1720 pub mac_count: i64,
1721 #[sqlx(default)]
1722 pub windows_count: i64,
1723}
1724
1725#[derive(FromRow, PartialEq, Debug, Serialize, Deserialize)]
1726pub struct Invite {
1727 pub email_address: String,
1728 pub email_confirmation_code: String,
1729}
1730
1731#[derive(Debug, Serialize, Deserialize)]
1732pub struct NewUserParams {
1733 pub github_login: String,
1734 pub github_user_id: i32,
1735 pub invite_count: i32,
1736}
1737
1738#[derive(Debug)]
1739pub struct NewUserResult {
1740 pub user_id: UserId,
1741 pub metrics_id: String,
1742 pub inviting_user_id: Option<UserId>,
1743 pub signup_device_id: Option<String>,
1744}
1745
1746fn random_invite_code() -> String {
1747 nanoid::nanoid!(16)
1748}
1749
1750fn random_email_confirmation_code() -> String {
1751 nanoid::nanoid!(64)
1752}
1753
1754#[cfg(test)]
1755pub use test::*;
1756
1757#[cfg(test)]
1758mod test {
1759 use super::*;
1760 use anyhow::anyhow;
1761 use collections::BTreeMap;
1762 use gpui::executor::Background;
1763 use lazy_static::lazy_static;
1764 use parking_lot::Mutex;
1765 use rand::prelude::*;
1766 use sqlx::{
1767 migrate::{MigrateDatabase, Migrator},
1768 Postgres,
1769 };
1770 use std::{path::Path, sync::Arc};
1771 use util::post_inc;
1772
1773 pub struct FakeDb {
1774 background: Arc<Background>,
1775 pub users: Mutex<BTreeMap<UserId, User>>,
1776 pub projects: Mutex<BTreeMap<ProjectId, Project>>,
1777 pub worktree_extensions: Mutex<BTreeMap<(ProjectId, u64, String), u32>>,
1778 pub orgs: Mutex<BTreeMap<OrgId, Org>>,
1779 pub org_memberships: Mutex<BTreeMap<(OrgId, UserId), bool>>,
1780 pub channels: Mutex<BTreeMap<ChannelId, Channel>>,
1781 pub channel_memberships: Mutex<BTreeMap<(ChannelId, UserId), bool>>,
1782 pub channel_messages: Mutex<BTreeMap<MessageId, ChannelMessage>>,
1783 pub contacts: Mutex<Vec<FakeContact>>,
1784 next_channel_message_id: Mutex<i32>,
1785 next_user_id: Mutex<i32>,
1786 next_org_id: Mutex<i32>,
1787 next_channel_id: Mutex<i32>,
1788 next_project_id: Mutex<i32>,
1789 }
1790
1791 #[derive(Debug)]
1792 pub struct FakeContact {
1793 pub requester_id: UserId,
1794 pub responder_id: UserId,
1795 pub accepted: bool,
1796 pub should_notify: bool,
1797 }
1798
1799 impl FakeDb {
1800 pub fn new(background: Arc<Background>) -> Self {
1801 Self {
1802 background,
1803 users: Default::default(),
1804 next_user_id: Mutex::new(0),
1805 projects: Default::default(),
1806 worktree_extensions: Default::default(),
1807 next_project_id: Mutex::new(1),
1808 orgs: Default::default(),
1809 next_org_id: Mutex::new(1),
1810 org_memberships: Default::default(),
1811 channels: Default::default(),
1812 next_channel_id: Mutex::new(1),
1813 channel_memberships: Default::default(),
1814 channel_messages: Default::default(),
1815 next_channel_message_id: Mutex::new(1),
1816 contacts: Default::default(),
1817 }
1818 }
1819 }
1820
1821 #[async_trait]
1822 impl Db for FakeDb {
1823 async fn create_user(
1824 &self,
1825 email_address: &str,
1826 admin: bool,
1827 params: NewUserParams,
1828 ) -> Result<NewUserResult> {
1829 self.background.simulate_random_delay().await;
1830
1831 let mut users = self.users.lock();
1832 let user_id = if let Some(user) = users
1833 .values()
1834 .find(|user| user.github_login == params.github_login)
1835 {
1836 user.id
1837 } else {
1838 let id = post_inc(&mut *self.next_user_id.lock());
1839 let user_id = UserId(id);
1840 users.insert(
1841 user_id,
1842 User {
1843 id: user_id,
1844 github_login: params.github_login,
1845 github_user_id: Some(params.github_user_id),
1846 email_address: Some(email_address.to_string()),
1847 admin,
1848 invite_code: None,
1849 invite_count: 0,
1850 connected_once: false,
1851 },
1852 );
1853 user_id
1854 };
1855 Ok(NewUserResult {
1856 user_id,
1857 metrics_id: "the-metrics-id".to_string(),
1858 inviting_user_id: None,
1859 signup_device_id: None,
1860 })
1861 }
1862
1863 async fn get_all_users(&self, _page: u32, _limit: u32) -> Result<Vec<User>> {
1864 unimplemented!()
1865 }
1866
1867 async fn fuzzy_search_users(&self, _: &str, _: u32) -> Result<Vec<User>> {
1868 unimplemented!()
1869 }
1870
1871 async fn get_user_by_id(&self, id: UserId) -> Result<Option<User>> {
1872 self.background.simulate_random_delay().await;
1873 Ok(self.get_users_by_ids(vec![id]).await?.into_iter().next())
1874 }
1875
1876 async fn get_user_metrics_id(&self, _id: UserId) -> Result<String> {
1877 Ok("the-metrics-id".to_string())
1878 }
1879
1880 async fn get_users_by_ids(&self, ids: Vec<UserId>) -> Result<Vec<User>> {
1881 self.background.simulate_random_delay().await;
1882 let users = self.users.lock();
1883 Ok(ids.iter().filter_map(|id| users.get(id).cloned()).collect())
1884 }
1885
1886 async fn get_users_with_no_invites(&self, _: bool) -> Result<Vec<User>> {
1887 unimplemented!()
1888 }
1889
1890 async fn get_user_by_github_account(
1891 &self,
1892 github_login: &str,
1893 github_user_id: Option<i32>,
1894 ) -> Result<Option<User>> {
1895 self.background.simulate_random_delay().await;
1896 if let Some(github_user_id) = github_user_id {
1897 for user in self.users.lock().values_mut() {
1898 if user.github_user_id == Some(github_user_id) {
1899 user.github_login = github_login.into();
1900 return Ok(Some(user.clone()));
1901 }
1902 if user.github_login == github_login {
1903 user.github_user_id = Some(github_user_id);
1904 return Ok(Some(user.clone()));
1905 }
1906 }
1907 Ok(None)
1908 } else {
1909 Ok(self
1910 .users
1911 .lock()
1912 .values()
1913 .find(|user| user.github_login == github_login)
1914 .cloned())
1915 }
1916 }
1917
1918 async fn set_user_is_admin(&self, _id: UserId, _is_admin: bool) -> Result<()> {
1919 unimplemented!()
1920 }
1921
1922 async fn set_user_connected_once(&self, id: UserId, connected_once: bool) -> Result<()> {
1923 self.background.simulate_random_delay().await;
1924 let mut users = self.users.lock();
1925 let mut user = users
1926 .get_mut(&id)
1927 .ok_or_else(|| anyhow!("user not found"))?;
1928 user.connected_once = connected_once;
1929 Ok(())
1930 }
1931
1932 async fn destroy_user(&self, _id: UserId) -> Result<()> {
1933 unimplemented!()
1934 }
1935
1936 // signups
1937
1938 async fn create_signup(&self, _signup: Signup) -> Result<()> {
1939 unimplemented!()
1940 }
1941
1942 async fn get_waitlist_summary(&self) -> Result<WaitlistSummary> {
1943 unimplemented!()
1944 }
1945
1946 async fn get_unsent_invites(&self, _count: usize) -> Result<Vec<Invite>> {
1947 unimplemented!()
1948 }
1949
1950 async fn record_sent_invites(&self, _invites: &[Invite]) -> Result<()> {
1951 unimplemented!()
1952 }
1953
1954 async fn create_user_from_invite(
1955 &self,
1956 _invite: &Invite,
1957 _user: NewUserParams,
1958 ) -> Result<NewUserResult> {
1959 unimplemented!()
1960 }
1961
1962 // invite codes
1963
1964 async fn set_invite_count_for_user(&self, _id: UserId, _count: u32) -> Result<()> {
1965 unimplemented!()
1966 }
1967
1968 async fn get_invite_code_for_user(&self, _id: UserId) -> Result<Option<(String, u32)>> {
1969 self.background.simulate_random_delay().await;
1970 Ok(None)
1971 }
1972
1973 async fn get_user_for_invite_code(&self, _code: &str) -> Result<User> {
1974 unimplemented!()
1975 }
1976
1977 async fn create_invite_from_code(
1978 &self,
1979 _code: &str,
1980 _email_address: &str,
1981 _device_id: Option<&str>,
1982 ) -> Result<Invite> {
1983 unimplemented!()
1984 }
1985
1986 // projects
1987
1988 async fn register_project(&self, host_user_id: UserId) -> Result<ProjectId> {
1989 self.background.simulate_random_delay().await;
1990 if !self.users.lock().contains_key(&host_user_id) {
1991 Err(anyhow!("no such user"))?;
1992 }
1993
1994 let project_id = ProjectId(post_inc(&mut *self.next_project_id.lock()));
1995 self.projects.lock().insert(
1996 project_id,
1997 Project {
1998 id: project_id,
1999 host_user_id,
2000 unregistered: false,
2001 },
2002 );
2003 Ok(project_id)
2004 }
2005
2006 async fn unregister_project(&self, project_id: ProjectId) -> Result<()> {
2007 self.background.simulate_random_delay().await;
2008 self.projects
2009 .lock()
2010 .get_mut(&project_id)
2011 .ok_or_else(|| anyhow!("no such project"))?
2012 .unregistered = true;
2013 Ok(())
2014 }
2015
2016 async fn update_worktree_extensions(
2017 &self,
2018 project_id: ProjectId,
2019 worktree_id: u64,
2020 extensions: HashMap<String, u32>,
2021 ) -> Result<()> {
2022 self.background.simulate_random_delay().await;
2023 if !self.projects.lock().contains_key(&project_id) {
2024 Err(anyhow!("no such project"))?;
2025 }
2026
2027 for (extension, count) in extensions {
2028 self.worktree_extensions
2029 .lock()
2030 .insert((project_id, worktree_id, extension), count);
2031 }
2032
2033 Ok(())
2034 }
2035
2036 async fn get_project_extensions(
2037 &self,
2038 _project_id: ProjectId,
2039 ) -> Result<HashMap<u64, HashMap<String, usize>>> {
2040 unimplemented!()
2041 }
2042
2043 async fn record_user_activity(
2044 &self,
2045 _time_period: Range<OffsetDateTime>,
2046 _active_projects: &[(UserId, ProjectId)],
2047 ) -> Result<()> {
2048 unimplemented!()
2049 }
2050
2051 async fn get_active_user_count(
2052 &self,
2053 _time_period: Range<OffsetDateTime>,
2054 _min_duration: Duration,
2055 _only_collaborative: bool,
2056 ) -> Result<usize> {
2057 unimplemented!()
2058 }
2059
2060 async fn get_top_users_activity_summary(
2061 &self,
2062 _time_period: Range<OffsetDateTime>,
2063 _limit: usize,
2064 ) -> Result<Vec<UserActivitySummary>> {
2065 unimplemented!()
2066 }
2067
2068 async fn get_user_activity_timeline(
2069 &self,
2070 _time_period: Range<OffsetDateTime>,
2071 _user_id: UserId,
2072 ) -> Result<Vec<UserActivityPeriod>> {
2073 unimplemented!()
2074 }
2075
2076 // contacts
2077
2078 async fn get_contacts(&self, id: UserId) -> Result<Vec<Contact>> {
2079 self.background.simulate_random_delay().await;
2080 let mut contacts = Vec::new();
2081
2082 for contact in self.contacts.lock().iter() {
2083 if contact.requester_id == id {
2084 if contact.accepted {
2085 contacts.push(Contact::Accepted {
2086 user_id: contact.responder_id,
2087 should_notify: contact.should_notify,
2088 });
2089 } else {
2090 contacts.push(Contact::Outgoing {
2091 user_id: contact.responder_id,
2092 });
2093 }
2094 } else if contact.responder_id == id {
2095 if contact.accepted {
2096 contacts.push(Contact::Accepted {
2097 user_id: contact.requester_id,
2098 should_notify: false,
2099 });
2100 } else {
2101 contacts.push(Contact::Incoming {
2102 user_id: contact.requester_id,
2103 should_notify: contact.should_notify,
2104 });
2105 }
2106 }
2107 }
2108
2109 contacts.sort_unstable_by_key(|contact| contact.user_id());
2110 Ok(contacts)
2111 }
2112
2113 async fn has_contact(&self, user_id_a: UserId, user_id_b: UserId) -> Result<bool> {
2114 self.background.simulate_random_delay().await;
2115 Ok(self.contacts.lock().iter().any(|contact| {
2116 contact.accepted
2117 && ((contact.requester_id == user_id_a && contact.responder_id == user_id_b)
2118 || (contact.requester_id == user_id_b && contact.responder_id == user_id_a))
2119 }))
2120 }
2121
2122 async fn send_contact_request(
2123 &self,
2124 requester_id: UserId,
2125 responder_id: UserId,
2126 ) -> Result<()> {
2127 self.background.simulate_random_delay().await;
2128 let mut contacts = self.contacts.lock();
2129 for contact in contacts.iter_mut() {
2130 if contact.requester_id == requester_id && contact.responder_id == responder_id {
2131 if contact.accepted {
2132 Err(anyhow!("contact already exists"))?;
2133 } else {
2134 Err(anyhow!("contact already requested"))?;
2135 }
2136 }
2137 if contact.responder_id == requester_id && contact.requester_id == responder_id {
2138 if contact.accepted {
2139 Err(anyhow!("contact already exists"))?;
2140 } else {
2141 contact.accepted = true;
2142 contact.should_notify = false;
2143 return Ok(());
2144 }
2145 }
2146 }
2147 contacts.push(FakeContact {
2148 requester_id,
2149 responder_id,
2150 accepted: false,
2151 should_notify: true,
2152 });
2153 Ok(())
2154 }
2155
2156 async fn remove_contact(&self, requester_id: UserId, responder_id: UserId) -> Result<()> {
2157 self.background.simulate_random_delay().await;
2158 self.contacts.lock().retain(|contact| {
2159 !(contact.requester_id == requester_id && contact.responder_id == responder_id)
2160 });
2161 Ok(())
2162 }
2163
2164 async fn dismiss_contact_notification(
2165 &self,
2166 user_id: UserId,
2167 contact_user_id: UserId,
2168 ) -> Result<()> {
2169 self.background.simulate_random_delay().await;
2170 let mut contacts = self.contacts.lock();
2171 for contact in contacts.iter_mut() {
2172 if contact.requester_id == contact_user_id
2173 && contact.responder_id == user_id
2174 && !contact.accepted
2175 {
2176 contact.should_notify = false;
2177 return Ok(());
2178 }
2179 if contact.requester_id == user_id
2180 && contact.responder_id == contact_user_id
2181 && contact.accepted
2182 {
2183 contact.should_notify = false;
2184 return Ok(());
2185 }
2186 }
2187 Err(anyhow!("no such notification"))?
2188 }
2189
2190 async fn respond_to_contact_request(
2191 &self,
2192 responder_id: UserId,
2193 requester_id: UserId,
2194 accept: bool,
2195 ) -> Result<()> {
2196 self.background.simulate_random_delay().await;
2197 let mut contacts = self.contacts.lock();
2198 for (ix, contact) in contacts.iter_mut().enumerate() {
2199 if contact.requester_id == requester_id && contact.responder_id == responder_id {
2200 if contact.accepted {
2201 Err(anyhow!("contact already confirmed"))?;
2202 }
2203 if accept {
2204 contact.accepted = true;
2205 contact.should_notify = true;
2206 } else {
2207 contacts.remove(ix);
2208 }
2209 return Ok(());
2210 }
2211 }
2212 Err(anyhow!("no such contact request"))?
2213 }
2214
2215 async fn create_access_token_hash(
2216 &self,
2217 _user_id: UserId,
2218 _access_token_hash: &str,
2219 _max_access_token_count: usize,
2220 ) -> Result<()> {
2221 unimplemented!()
2222 }
2223
2224 async fn get_access_token_hashes(&self, _user_id: UserId) -> Result<Vec<String>> {
2225 unimplemented!()
2226 }
2227
2228 async fn find_org_by_slug(&self, _slug: &str) -> Result<Option<Org>> {
2229 unimplemented!()
2230 }
2231
2232 async fn create_org(&self, name: &str, slug: &str) -> Result<OrgId> {
2233 self.background.simulate_random_delay().await;
2234 let mut orgs = self.orgs.lock();
2235 if orgs.values().any(|org| org.slug == slug) {
2236 Err(anyhow!("org already exists"))?
2237 } else {
2238 let org_id = OrgId(post_inc(&mut *self.next_org_id.lock()));
2239 orgs.insert(
2240 org_id,
2241 Org {
2242 id: org_id,
2243 name: name.to_string(),
2244 slug: slug.to_string(),
2245 },
2246 );
2247 Ok(org_id)
2248 }
2249 }
2250
2251 async fn add_org_member(
2252 &self,
2253 org_id: OrgId,
2254 user_id: UserId,
2255 is_admin: bool,
2256 ) -> Result<()> {
2257 self.background.simulate_random_delay().await;
2258 if !self.orgs.lock().contains_key(&org_id) {
2259 Err(anyhow!("org does not exist"))?;
2260 }
2261 if !self.users.lock().contains_key(&user_id) {
2262 Err(anyhow!("user does not exist"))?;
2263 }
2264
2265 self.org_memberships
2266 .lock()
2267 .entry((org_id, user_id))
2268 .or_insert(is_admin);
2269 Ok(())
2270 }
2271
2272 async fn create_org_channel(&self, org_id: OrgId, name: &str) -> Result<ChannelId> {
2273 self.background.simulate_random_delay().await;
2274 if !self.orgs.lock().contains_key(&org_id) {
2275 Err(anyhow!("org does not exist"))?;
2276 }
2277
2278 let mut channels = self.channels.lock();
2279 let channel_id = ChannelId(post_inc(&mut *self.next_channel_id.lock()));
2280 channels.insert(
2281 channel_id,
2282 Channel {
2283 id: channel_id,
2284 name: name.to_string(),
2285 owner_id: org_id.0,
2286 owner_is_user: false,
2287 },
2288 );
2289 Ok(channel_id)
2290 }
2291
2292 async fn get_org_channels(&self, org_id: OrgId) -> Result<Vec<Channel>> {
2293 self.background.simulate_random_delay().await;
2294 Ok(self
2295 .channels
2296 .lock()
2297 .values()
2298 .filter(|channel| !channel.owner_is_user && channel.owner_id == org_id.0)
2299 .cloned()
2300 .collect())
2301 }
2302
2303 async fn get_accessible_channels(&self, user_id: UserId) -> Result<Vec<Channel>> {
2304 self.background.simulate_random_delay().await;
2305 let channels = self.channels.lock();
2306 let memberships = self.channel_memberships.lock();
2307 Ok(channels
2308 .values()
2309 .filter(|channel| memberships.contains_key(&(channel.id, user_id)))
2310 .cloned()
2311 .collect())
2312 }
2313
2314 async fn can_user_access_channel(
2315 &self,
2316 user_id: UserId,
2317 channel_id: ChannelId,
2318 ) -> Result<bool> {
2319 self.background.simulate_random_delay().await;
2320 Ok(self
2321 .channel_memberships
2322 .lock()
2323 .contains_key(&(channel_id, user_id)))
2324 }
2325
2326 async fn add_channel_member(
2327 &self,
2328 channel_id: ChannelId,
2329 user_id: UserId,
2330 is_admin: bool,
2331 ) -> Result<()> {
2332 self.background.simulate_random_delay().await;
2333 if !self.channels.lock().contains_key(&channel_id) {
2334 Err(anyhow!("channel does not exist"))?;
2335 }
2336 if !self.users.lock().contains_key(&user_id) {
2337 Err(anyhow!("user does not exist"))?;
2338 }
2339
2340 self.channel_memberships
2341 .lock()
2342 .entry((channel_id, user_id))
2343 .or_insert(is_admin);
2344 Ok(())
2345 }
2346
2347 async fn create_channel_message(
2348 &self,
2349 channel_id: ChannelId,
2350 sender_id: UserId,
2351 body: &str,
2352 timestamp: OffsetDateTime,
2353 nonce: u128,
2354 ) -> Result<MessageId> {
2355 self.background.simulate_random_delay().await;
2356 if !self.channels.lock().contains_key(&channel_id) {
2357 Err(anyhow!("channel does not exist"))?;
2358 }
2359 if !self.users.lock().contains_key(&sender_id) {
2360 Err(anyhow!("user does not exist"))?;
2361 }
2362
2363 let mut messages = self.channel_messages.lock();
2364 if let Some(message) = messages
2365 .values()
2366 .find(|message| message.nonce.as_u128() == nonce)
2367 {
2368 Ok(message.id)
2369 } else {
2370 let message_id = MessageId(post_inc(&mut *self.next_channel_message_id.lock()));
2371 messages.insert(
2372 message_id,
2373 ChannelMessage {
2374 id: message_id,
2375 channel_id,
2376 sender_id,
2377 body: body.to_string(),
2378 sent_at: timestamp,
2379 nonce: Uuid::from_u128(nonce),
2380 },
2381 );
2382 Ok(message_id)
2383 }
2384 }
2385
2386 async fn get_channel_messages(
2387 &self,
2388 channel_id: ChannelId,
2389 count: usize,
2390 before_id: Option<MessageId>,
2391 ) -> Result<Vec<ChannelMessage>> {
2392 self.background.simulate_random_delay().await;
2393 let mut messages = self
2394 .channel_messages
2395 .lock()
2396 .values()
2397 .rev()
2398 .filter(|message| {
2399 message.channel_id == channel_id
2400 && message.id < before_id.unwrap_or(MessageId::MAX)
2401 })
2402 .take(count)
2403 .cloned()
2404 .collect::<Vec<_>>();
2405 messages.sort_unstable_by_key(|message| message.id);
2406 Ok(messages)
2407 }
2408
2409 async fn teardown(&self, _: &str) {}
2410
2411 #[cfg(test)]
2412 fn as_fake(&self) -> Option<&FakeDb> {
2413 Some(self)
2414 }
2415 }
2416
2417 pub struct TestDb {
2418 pub db: Option<Arc<dyn Db>>,
2419 pub url: String,
2420 }
2421
2422 impl TestDb {
2423 #[allow(clippy::await_holding_lock)]
2424 pub async fn postgres() -> Self {
2425 lazy_static! {
2426 static ref LOCK: Mutex<()> = Mutex::new(());
2427 }
2428
2429 let _guard = LOCK.lock();
2430 let mut rng = StdRng::from_entropy();
2431 let name = format!("zed-test-{}", rng.gen::<u128>());
2432 let url = format!("postgres://postgres@localhost/{}", name);
2433 let migrations_path = Path::new(concat!(env!("CARGO_MANIFEST_DIR"), "/migrations"));
2434 Postgres::create_database(&url)
2435 .await
2436 .expect("failed to create test db");
2437 let db = PostgresDb::new(&url, 5).await.unwrap();
2438 let migrator = Migrator::new(migrations_path).await.unwrap();
2439 migrator.run(&db.pool).await.unwrap();
2440 Self {
2441 db: Some(Arc::new(db)),
2442 url,
2443 }
2444 }
2445
2446 pub fn fake(background: Arc<Background>) -> Self {
2447 Self {
2448 db: Some(Arc::new(FakeDb::new(background))),
2449 url: Default::default(),
2450 }
2451 }
2452
2453 pub fn db(&self) -> &Arc<dyn Db> {
2454 self.db.as_ref().unwrap()
2455 }
2456 }
2457
2458 impl Drop for TestDb {
2459 fn drop(&mut self) {
2460 if let Some(db) = self.db.take() {
2461 futures::executor::block_on(db.teardown(&self.url));
2462 }
2463 }
2464 }
2465}