Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
7 changes: 7 additions & 0 deletions migrations/2025-01-19-212212_issues-to-tasks/down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
DELETE FROM tasks
WHERE type = 'dev'
AND id IN (SELECT id FROM issues);

DELETE FROM users_projects_roles
WHERE role_id = 2
AND user_id IN (SELECT DISTINCT assignee_id FROM issues WHERE assignee_id IS NOT NULL);
60 changes: 60 additions & 0 deletions migrations/2025-01-19-212212_issues-to-tasks/up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,60 @@
-- Migrate issues to tasks

INSERT INTO tasks (
id,
number,
repository_id,
title,
description,
labels,
open,
is_certified,
assignee_user_id,
issue_created_at,
issue_closed_at,
created_at,
updated_at,
type,
status,
url
)
SELECT
i.id,
i.number,
i.repository_id,
i.title,
i.description,
i.labels,
i.open,
COALESCE(i.certified, false) AS is_certified,
i.assignee_id AS assignee_user_id,
i.issue_created_at,
i.issue_closed_at,
i.created_at,
i.updated_at,
'dev' AS type,
CASE
WHEN i.open = TRUE AND i.assignee_id IS NULL THEN 'open'
WHEN i.open = TRUE AND i.assignee_id IS NOT NULL THEN 'in-progress'
WHEN i.open = FALSE THEN 'completed'
END AS status,
CONCAT(
'https://github.com/',
r.slug,
'/issues/',
i.number
) AS url
FROM
issues i
JOIN
repositories r
ON
i.repository_id = r.id;

-- add CONTRIBUTOR role

INSERT INTO users_projects_roles (user_id, role_id)
SELECT DISTINCT assignee_id AS user_id, 2 AS role_id
FROM issues
WHERE assignee_id IS NOT NULL
ON CONFLICT (user_id, project_id, role_id) DO NOTHING;
2 changes: 2 additions & 0 deletions migrations/2025-01-19-215731_contributor-role/down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
DROP TRIGGER IF EXISTS trigger_assign_role_to_user ON tasks;
DROP FUNCTION IF EXISTS assign_role_to_user;
21 changes: 21 additions & 0 deletions migrations/2025-01-19-215731_contributor-role/up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
CREATE OR REPLACE FUNCTION assign_role_to_user()
RETURNS TRIGGER AS $$
BEGIN
IF NEW.assignee_user_id IS NOT NULL THEN
INSERT INTO users_projects_roles (user_id, role_id)
SELECT NEW.assignee_user_id, 2
WHERE NOT EXISTS (
SELECT 1
FROM users_projects_roles
WHERE user_id = NEW.assignee_user_id
AND role_id = 2
);
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER trigger_assign_role_to_user
AFTER INSERT OR UPDATE OF assignee_user_id ON tasks
FOR EACH ROW
EXECUTE FUNCTION assign_role_to_user();
2 changes: 2 additions & 0 deletions migrations/2025-01-19-223138_tasks-status/down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
DROP TRIGGER IF EXISTS update_task_status_trigger ON tasks;
DROP FUNCTION IF EXISTS update_task_status;
16 changes: 16 additions & 0 deletions migrations/2025-01-19-223138_tasks-status/up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@

CREATE OR REPLACE FUNCTION update_task_status() RETURNS TRIGGER AS $$
BEGIN
NEW.status := CASE
WHEN NEW.open = TRUE AND NEW.assignee_user_id IS NULL THEN 'open'
WHEN NEW.open = TRUE AND NEW.assignee_user_id IS NOT NULL THEN 'in-progress'
WHEN NEW.open = FALSE THEN 'completed'
END;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER update_task_status_trigger
BEFORE INSERT OR UPDATE ON tasks
FOR EACH ROW
EXECUTE FUNCTION update_task_status();
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
ALTER TABLE tasks
DROP CONSTRAINT tasks_repo_number_unique;
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
ALTER TABLE tasks
ADD CONSTRAINT tasks_repo_number_unique UNIQUE (repository_id, number);
3 changes: 3 additions & 0 deletions migrations/2025-01-29-212647_repository-id/down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@

ALTER TABLE tasks
DROP CONSTRAINT tasks_repository_id_fkey;
6 changes: 6 additions & 0 deletions migrations/2025-01-29-212647_repository-id/up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@

ALTER TABLE tasks
ADD CONSTRAINT tasks_repository_id_fkey
FOREIGN KEY (repository_id)
REFERENCES repositories(id)
ON DELETE CASCADE;
8 changes: 8 additions & 0 deletions migrations/2025-01-29-212911_project-id/down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@

DROP TRIGGER IF EXISTS trigger_set_project_id ON tasks;
DROP FUNCTION IF EXISTS set_project_id_from_repository;
ALTER TABLE tasks
DROP CONSTRAINT tasks_repository_id_fkey;

ALTER TABLE repositories
DROP CONSTRAINT unique_id_project_id;
16 changes: 16 additions & 0 deletions migrations/2025-01-29-212911_project-id/up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
ALTER TABLE repositories
ADD CONSTRAINT unique_id_project_id UNIQUE (id, project_id);

CREATE OR REPLACE FUNCTION set_project_id_from_repository()
RETURNS TRIGGER AS $$
BEGIN
NEW.project_id := (SELECT project_id FROM repositories WHERE id = NEW.repository_id);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER trigger_set_project_id
BEFORE INSERT OR UPDATE ON tasks
FOR EACH ROW
WHEN (NEW.repository_id IS NOT NULL AND NEW.project_id IS NULL)
EXECUTE FUNCTION set_project_id_from_repository();
193 changes: 177 additions & 16 deletions src/api/tasks/db.rs
Original file line number Diff line number Diff line change
@@ -1,6 +1,9 @@
use diesel::prelude::*;

use crate::schema::tasks::dsl as tasks_dsl;
use crate::schema::users::dsl as users_dsl;
use crate::schema::repositories::dsl as repositories_dsl;
use crate::schema::projects::dsl as projects_dsl;
use crate::schema::tasks_votes::dsl as tasks_votes_dsl;

use crate::db::{
Expand All @@ -9,15 +12,19 @@ use crate::db::{
};
use crate::types::PaginationParams;
use crate::utils;
use crate::api::users::models::User;
use crate::api::projects::models::{ProjectResponse, Project};
use crate::api::repositories::models::{RepositoryResponse, Repository};

use super::models::{NewTask, QueryParams, Task, TaskVote, TaskVoteDB, UpdateTask};

use super::models::{NewTask, QueryParams, Task, TaskVote, TaskVoteDB, UpdateTask, TaskResponse};
pub trait DBTask: Send + Sync + Clone + 'static {
fn all(
&self,
params: QueryParams,
pagination: PaginationParams,
) -> Result<(Vec<Task>, i64), DBError>;
fn by_id(&self, id: i32) -> Result<Option<Task>, DBError>;
) -> Result<(Vec<TaskResponse>, i64), DBError>;
fn by_id(&self, id: i32) -> Result<Option<TaskResponse>, DBError>;
fn create(&self, role: &NewTask) -> Result<Task, DBError>;
fn update(&self, id: i32, role: &UpdateTask) -> Result<Task, DBError>;
fn delete(&self, id: i32) -> Result<(), DBError>;
Expand All @@ -30,11 +37,25 @@ impl DBTask for DBAccess {
&self,
params: QueryParams,
pagination: PaginationParams,
) -> Result<(Vec<Task>, i64), DBError> {
) -> Result<(Vec<TaskResponse>, i64), DBError> {
let conn = &mut self.get_db_conn();

let build_query = || {
let mut query = tasks_dsl::tasks.into_boxed();
let mut query = tasks_dsl::tasks
.left_join(
repositories_dsl::repositories
.on(tasks_dsl::repository_id.eq(repositories_dsl::id.nullable()))
)
.inner_join(
projects_dsl::projects
.on(repositories_dsl::project_id.eq(projects_dsl::id))
)
.left_join(
users_dsl::users
.on(tasks_dsl::assignee_user_id.eq(users_dsl::id.nullable()))
)
.into_boxed();


if let Some(repository_id) = params.repository_id {
query = query.filter(tasks_dsl::repository_id.eq(repository_id));
Expand Down Expand Up @@ -106,24 +127,164 @@ impl DBTask for DBAccess {

let total_count = build_query().count().get_result::<i64>(conn)?;

let result = build_query()
let query = build_query()
.select((
(tasks_dsl::tasks::all_columns()),
(repositories_dsl::repositories::all_columns().nullable()),
(projects_dsl::projects::all_columns()),
(users_dsl::users::all_columns().nullable()),
))
.order(tasks_dsl::created_at.desc())
.offset(pagination.offset)
.limit(pagination.limit)
.load::<Task>(conn)?;
.limit(pagination.limit);

let rows = query.load::<(Task, Option<Repository>, Project, Option<User>)>(conn)?;

Ok((result, total_count))
let tasks_with_assignee = rows
.into_iter()
.map(|(task, repo, project, user)| TaskResponse {
id: task.id,
number: task.number,
repository_id: task.repository_id,
title: task.title,
description: task.description,
url: task.url,
labels: task.labels,
open: task.open,
type_: task.type_,
project_id: task.project_id,
created_by_user_id: task.created_by_user_id,
assignee_user_id: task.assignee_user_id,
user,
repository: repo.map(|r| RepositoryResponse {
id: r.id,
slug: r.slug,
name: r.name,
url: r.url,
language_slug: r.language_slug,
project: ProjectResponse {
id: project.id,
name: project.name,
slug: project.slug,
purposes: project.purposes,
stack_levels: project.stack_levels,
technologies: project.technologies,
avatar: project.avatar,
created_at: project.created_at,
updated_at: project.updated_at,
rewards: project.rewards,
},
created_at: r.created_at,
updated_at: r.updated_at,
}),
assignee_team_id: task.assignee_team_id,
funding_options: task.funding_options,
contact: task.contact,
skills: task.skills,
bounty: task.bounty,
approved_by: task.approved_by,
approved_at: task.approved_at,
status: task.status,
upvotes: task.upvotes,
downvotes: task.downvotes,
is_featured: task.is_featured,
is_certified: task.is_certified,
featured_by_user_id: task.featured_by_user_id,
issue_created_at: task.issue_created_at,
issue_closed_at: task.issue_closed_at,
created_at: task.created_at,
updated_at: task.updated_at,
})
.collect();

Ok((tasks_with_assignee, total_count))
}

fn by_id(&self, id: i32) -> Result<Option<Task>, DBError> {
fn by_id(&self, id: i32) -> Result<Option<TaskResponse>, DBError> {
let conn = &mut self.get_db_conn();
let result = tasks_dsl::tasks
.find(id)
.first::<Task>(conn)
.optional()
.map_err(DBError::from)?;
Ok(result)

let row = tasks_dsl::tasks

.left_join(
repositories_dsl::repositories
.on(tasks_dsl::repository_id.eq(repositories_dsl::id.nullable()))
)

.inner_join(
projects_dsl::projects
.on(repositories_dsl::project_id.eq(projects_dsl::id))
)

.left_join(
users_dsl::users
.on(tasks_dsl::assignee_user_id.eq(users_dsl::id.nullable()))
)
.filter(tasks_dsl::id.eq(id))
.select((
(tasks_dsl::tasks::all_columns()),
(repositories_dsl::repositories::all_columns().nullable()),
(projects_dsl::projects::all_columns()),
(users_dsl::users::all_columns().nullable()),
))
.first::<(Task, Option<Repository>, Project, Option<User>)>(conn)
.optional()?;

Ok(row.map(|(task, repo, project, user)| TaskResponse {
id: task.id,
number: task.number,
repository_id: task.repository_id,
title: task.title,
description: task.description,
url: task.url,
labels: task.labels,
open: task.open,
type_: task.type_,
project_id: task.project_id,
created_by_user_id: task.created_by_user_id,
assignee_user_id: task.assignee_user_id,
user,
assignee_team_id: task.assignee_team_id,
funding_options: task.funding_options,
contact: task.contact,
skills: task.skills,
bounty: task.bounty,
approved_by: task.approved_by,
approved_at: task.approved_at,
status: task.status,
upvotes: task.upvotes,
downvotes: task.downvotes,
is_featured: task.is_featured,
is_certified: task.is_certified,
featured_by_user_id: task.featured_by_user_id,
issue_created_at: task.issue_created_at,
issue_closed_at: task.issue_closed_at,
created_at: task.created_at,
updated_at: task.updated_at,
repository: repo.map(|r| RepositoryResponse {
id: r.id,
slug: r.slug,
name: r.name,
url: r.url,
language_slug: r.language_slug,
project: ProjectResponse {
id: project.id,
name: project.name,
slug: project.slug,
purposes: project.purposes,
stack_levels: project.stack_levels,
technologies: project.technologies,
avatar: project.avatar,
created_at: project.created_at,
updated_at: project.updated_at,
rewards: project.rewards,
},
created_at: r.created_at,
updated_at: r.updated_at,
}),
}))
}



fn create(&self, task: &NewTask) -> Result<Task, DBError> {
let conn = &mut self.get_db_conn();
Expand Down
Loading