193 lines
5.2 KiB
SQL
193 lines
5.2 KiB
SQL
-- Фаза 3: Отклики волонтеров и история статусов (СРЕДНИЙ ПРИОРИТЕТ)
|
|
-- Запросы для управления откликами волонтеров и историей изменения статусов заявок
|
|
|
|
-- ============================================================================
|
|
-- Отклики волонтеров
|
|
-- ============================================================================
|
|
|
|
-- name: CreateVolunteerResponse :one
|
|
INSERT INTO volunteer_responses (
|
|
request_id,
|
|
volunteer_id,
|
|
message
|
|
) VALUES (
|
|
$1,
|
|
$2,
|
|
$3
|
|
)
|
|
ON CONFLICT (request_id, volunteer_id) DO NOTHING
|
|
RETURNING *;
|
|
|
|
-- name: GetResponsesByRequest :many
|
|
SELECT
|
|
vr.*,
|
|
(u.first_name || ' ' || u.last_name) as volunteer_name,
|
|
u.avatar_url as volunteer_avatar,
|
|
u.volunteer_rating,
|
|
u.completed_requests_count,
|
|
u.email as volunteer_email,
|
|
u.phone as volunteer_phone
|
|
FROM volunteer_responses vr
|
|
JOIN users u ON u.id = vr.volunteer_id
|
|
WHERE vr.request_id = $1
|
|
ORDER BY vr.created_at DESC;
|
|
|
|
-- name: GetResponsesByVolunteer :many
|
|
SELECT
|
|
vr.*,
|
|
r.title as request_title,
|
|
r.status as request_status,
|
|
(u.first_name || ' ' || u.last_name) as requester_name
|
|
FROM volunteer_responses vr
|
|
JOIN requests r ON r.id = vr.request_id
|
|
JOIN users u ON u.id = r.requester_id
|
|
WHERE vr.volunteer_id = $1
|
|
ORDER BY vr.created_at DESC
|
|
LIMIT $2 OFFSET $3;
|
|
|
|
-- name: GetResponseByID :one
|
|
SELECT
|
|
vr.*,
|
|
(u.first_name || ' ' || u.last_name) as volunteer_name,
|
|
r.title as request_title
|
|
FROM volunteer_responses vr
|
|
JOIN users u ON u.id = vr.volunteer_id
|
|
JOIN requests r ON r.id = vr.request_id
|
|
WHERE vr.id = $1;
|
|
|
|
-- name: AcceptVolunteerResponse :exec
|
|
UPDATE volunteer_responses SET
|
|
status = 'accepted',
|
|
accepted_at = CURRENT_TIMESTAMP,
|
|
updated_at = CURRENT_TIMESTAMP
|
|
WHERE id = $1;
|
|
|
|
-- name: RejectVolunteerResponse :exec
|
|
UPDATE volunteer_responses SET
|
|
status = 'rejected',
|
|
rejected_at = CURRENT_TIMESTAMP,
|
|
updated_at = CURRENT_TIMESTAMP
|
|
WHERE id = $1;
|
|
|
|
-- name: CountResponsesByRequest :one
|
|
SELECT COUNT(*) FROM volunteer_responses
|
|
WHERE request_id = $1;
|
|
|
|
-- name: CountPendingResponsesByVolunteer :one
|
|
SELECT COUNT(*) FROM volunteer_responses
|
|
WHERE volunteer_id = $1 AND status = 'pending';
|
|
|
|
-- ============================================================================
|
|
-- История изменения статусов заявок
|
|
-- ============================================================================
|
|
|
|
-- name: CreateStatusHistoryEntry :one
|
|
INSERT INTO request_status_history (
|
|
request_id,
|
|
from_status,
|
|
to_status,
|
|
changed_by,
|
|
comment
|
|
) VALUES (
|
|
$1,
|
|
$2,
|
|
$3,
|
|
$4,
|
|
sqlc.narg('comment')
|
|
) RETURNING *;
|
|
|
|
-- name: GetRequestStatusHistory :many
|
|
SELECT
|
|
rsh.*,
|
|
(u.first_name || ' ' || u.last_name) as changed_by_name
|
|
FROM request_status_history rsh
|
|
JOIN users u ON u.id = rsh.changed_by
|
|
WHERE rsh.request_id = $1
|
|
ORDER BY rsh.created_at DESC;
|
|
|
|
-- name: GetLatestStatusChange :one
|
|
SELECT
|
|
rsh.*,
|
|
(u.first_name || ' ' || u.last_name) as changed_by_name
|
|
FROM request_status_history rsh
|
|
JOIN users u ON u.id = rsh.changed_by
|
|
WHERE rsh.request_id = $1
|
|
ORDER BY rsh.created_at DESC
|
|
LIMIT 1;
|
|
|
|
-- ============================================================================
|
|
-- Рейтинги
|
|
-- ============================================================================
|
|
|
|
-- name: CreateRating :one
|
|
INSERT INTO ratings (
|
|
volunteer_response_id,
|
|
volunteer_id,
|
|
requester_id,
|
|
request_id,
|
|
rating,
|
|
comment
|
|
) VALUES (
|
|
$1,
|
|
$2,
|
|
$3,
|
|
$4,
|
|
$5,
|
|
sqlc.narg('comment')
|
|
) RETURNING *;
|
|
|
|
-- name: GetRatingByResponseID :one
|
|
SELECT * FROM ratings
|
|
WHERE volunteer_response_id = $1;
|
|
|
|
-- name: GetRatingsByVolunteer :many
|
|
SELECT
|
|
r.*,
|
|
req.title as request_title,
|
|
(u.first_name || ' ' || u.last_name) as requester_name
|
|
FROM ratings r
|
|
JOIN requests req ON req.id = r.request_id
|
|
JOIN users u ON u.id = r.requester_id
|
|
WHERE r.volunteer_id = $1
|
|
ORDER BY r.created_at DESC
|
|
LIMIT $2 OFFSET $3;
|
|
|
|
-- name: CalculateVolunteerAverageRating :one
|
|
SELECT
|
|
COALESCE(AVG(rating), 0) as average_rating,
|
|
COUNT(*) as total_ratings
|
|
FROM ratings
|
|
WHERE volunteer_id = $1;
|
|
|
|
-- name: UpdateRating :exec
|
|
UPDATE ratings SET
|
|
rating = $2,
|
|
comment = sqlc.narg('comment'),
|
|
updated_at = CURRENT_TIMESTAMP
|
|
WHERE id = $1;
|
|
|
|
-- ============================================================================
|
|
-- Хранимые процедуры
|
|
-- ============================================================================
|
|
|
|
-- name: CallAcceptVolunteerResponse :one
|
|
SELECT
|
|
r.success::BOOLEAN,
|
|
r.message::TEXT,
|
|
r.out_request_id::BIGINT,
|
|
r.out_volunteer_id::BIGINT
|
|
FROM accept_volunteer_response($1, $2) AS r(success, message, out_request_id, out_volunteer_id);
|
|
|
|
-- name: CallCompleteRequestWithRating :one
|
|
SELECT
|
|
r.success::BOOLEAN,
|
|
r.message::TEXT,
|
|
r.out_rating_id::BIGINT
|
|
FROM complete_request_with_rating($1, $2, $3, sqlc.narg('comment')) AS r(success, message, out_rating_id);
|
|
|
|
-- name: CallModerateRequest :one
|
|
SELECT
|
|
r.success::BOOLEAN,
|
|
r.message::TEXT
|
|
FROM moderate_request($1, $2, $3, sqlc.narg('comment')) AS r(success, message);
|