initial commit
This commit is contained in:
194
internal/database/queries/auth.sql
Normal file
194
internal/database/queries/auth.sql
Normal file
@@ -0,0 +1,194 @@
|
||||
-- Фаза 1A: Аутентификация (КРИТИЧНО)
|
||||
-- Запросы для регистрации, входа и управления токенами
|
||||
|
||||
-- ============================================================================
|
||||
-- Пользователи
|
||||
-- ============================================================================
|
||||
|
||||
-- name: CreateUser :one
|
||||
INSERT INTO users (
|
||||
email,
|
||||
phone,
|
||||
password_hash,
|
||||
first_name,
|
||||
last_name,
|
||||
location,
|
||||
address,
|
||||
city
|
||||
) VALUES (
|
||||
$1,
|
||||
$2,
|
||||
$3,
|
||||
$4,
|
||||
$5,
|
||||
ST_SetSRID(ST_MakePoint($6, $7), 4326)::geography,
|
||||
$8,
|
||||
$9
|
||||
) RETURNING
|
||||
id,
|
||||
email,
|
||||
phone,
|
||||
password_hash,
|
||||
first_name,
|
||||
last_name,
|
||||
avatar_url,
|
||||
ST_Y(location::geometry) as latitude,
|
||||
ST_X(location::geometry) as longitude,
|
||||
address,
|
||||
city,
|
||||
volunteer_rating,
|
||||
completed_requests_count,
|
||||
is_verified,
|
||||
is_blocked,
|
||||
email_verified,
|
||||
created_at,
|
||||
updated_at,
|
||||
last_login_at,
|
||||
deleted_at;
|
||||
|
||||
-- name: GetUserByEmail :one
|
||||
SELECT
|
||||
id,
|
||||
email,
|
||||
phone,
|
||||
password_hash,
|
||||
first_name,
|
||||
last_name,
|
||||
avatar_url,
|
||||
ST_Y(location::geometry) as latitude,
|
||||
ST_X(location::geometry) as longitude,
|
||||
address,
|
||||
city,
|
||||
volunteer_rating,
|
||||
completed_requests_count,
|
||||
is_verified,
|
||||
is_blocked,
|
||||
email_verified,
|
||||
created_at,
|
||||
updated_at,
|
||||
last_login_at,
|
||||
deleted_at
|
||||
FROM users
|
||||
WHERE email = $1 AND deleted_at IS NULL;
|
||||
|
||||
-- name: GetUserByID :one
|
||||
SELECT
|
||||
id,
|
||||
email,
|
||||
phone,
|
||||
password_hash,
|
||||
first_name,
|
||||
last_name,
|
||||
avatar_url,
|
||||
ST_Y(location::geometry) as latitude,
|
||||
ST_X(location::geometry) as longitude,
|
||||
address,
|
||||
city,
|
||||
volunteer_rating,
|
||||
completed_requests_count,
|
||||
is_verified,
|
||||
is_blocked,
|
||||
email_verified,
|
||||
created_at,
|
||||
updated_at,
|
||||
last_login_at,
|
||||
deleted_at
|
||||
FROM users
|
||||
WHERE id = $1 AND deleted_at IS NULL;
|
||||
|
||||
-- name: EmailExists :one
|
||||
SELECT EXISTS(
|
||||
SELECT 1 FROM users
|
||||
WHERE email = $1 AND deleted_at IS NULL
|
||||
);
|
||||
|
||||
-- name: UpdateLastLogin :exec
|
||||
UPDATE users
|
||||
SET last_login_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- ============================================================================
|
||||
-- Refresh Tokens
|
||||
-- ============================================================================
|
||||
|
||||
-- name: CreateRefreshToken :one
|
||||
INSERT INTO refresh_tokens (
|
||||
user_id,
|
||||
token,
|
||||
expires_at,
|
||||
user_agent,
|
||||
ip_address
|
||||
) VALUES (
|
||||
$1,
|
||||
$2,
|
||||
$3,
|
||||
$4,
|
||||
$5
|
||||
) RETURNING *;
|
||||
|
||||
-- name: GetRefreshToken :one
|
||||
SELECT * FROM refresh_tokens
|
||||
WHERE token = $1
|
||||
AND revoked = FALSE
|
||||
AND expires_at > CURRENT_TIMESTAMP;
|
||||
|
||||
-- name: RevokeRefreshToken :exec
|
||||
UPDATE refresh_tokens
|
||||
SET revoked = TRUE, revoked_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: RevokeAllUserTokens :exec
|
||||
UPDATE refresh_tokens
|
||||
SET revoked = TRUE, revoked_at = CURRENT_TIMESTAMP
|
||||
WHERE user_id = $1 AND revoked = FALSE;
|
||||
|
||||
-- name: CleanupExpiredTokens :exec
|
||||
DELETE FROM refresh_tokens
|
||||
WHERE expires_at < CURRENT_TIMESTAMP
|
||||
OR (revoked = TRUE AND revoked_at < CURRENT_TIMESTAMP - INTERVAL '30 days');
|
||||
|
||||
-- ============================================================================
|
||||
-- User Sessions
|
||||
-- ============================================================================
|
||||
|
||||
-- name: CreateUserSession :one
|
||||
INSERT INTO user_sessions (
|
||||
user_id,
|
||||
session_token,
|
||||
refresh_token_id,
|
||||
expires_at,
|
||||
user_agent,
|
||||
ip_address,
|
||||
device_info
|
||||
) VALUES (
|
||||
$1,
|
||||
$2,
|
||||
$3,
|
||||
$4,
|
||||
$5,
|
||||
$6,
|
||||
$7
|
||||
) RETURNING *;
|
||||
|
||||
-- name: GetUserSession :one
|
||||
SELECT * FROM user_sessions
|
||||
WHERE session_token = $1
|
||||
AND expires_at > CURRENT_TIMESTAMP;
|
||||
|
||||
-- name: UpdateSessionActivity :exec
|
||||
UPDATE user_sessions
|
||||
SET last_activity_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: InvalidateUserSession :exec
|
||||
DELETE FROM user_sessions
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: InvalidateAllUserSessions :exec
|
||||
DELETE FROM user_sessions
|
||||
WHERE user_id = $1;
|
||||
|
||||
-- name: CleanupExpiredSessions :exec
|
||||
DELETE FROM user_sessions
|
||||
WHERE expires_at < CURRENT_TIMESTAMP
|
||||
OR last_activity_at < CURRENT_TIMESTAMP - INTERVAL '7 days';
|
||||
151
internal/database/queries/geospatial.sql
Normal file
151
internal/database/queries/geospatial.sql
Normal file
@@ -0,0 +1,151 @@
|
||||
-- Фаза 2B: Геопространственные запросы (ВЫСОКИЙ ПРИОРИТЕТ)
|
||||
-- PostGIS запросы для поиска заявок по геолокации
|
||||
|
||||
-- ============================================================================
|
||||
-- Поиск заявок рядом с точкой
|
||||
-- ============================================================================
|
||||
|
||||
-- name: FindRequestsNearby :many
|
||||
SELECT
|
||||
r.id,
|
||||
r.title,
|
||||
r.description,
|
||||
r.address,
|
||||
r.city,
|
||||
r.urgency,
|
||||
r.status,
|
||||
r.created_at,
|
||||
r.desired_completion_date,
|
||||
ST_Y(r.location::geometry) as latitude,
|
||||
ST_X(r.location::geometry) as longitude,
|
||||
ST_Distance(
|
||||
r.location,
|
||||
ST_SetSRID(ST_MakePoint($1, $2), 4326)::geography
|
||||
) as distance_meters,
|
||||
rt.name as request_type_name,
|
||||
rt.icon as request_type_icon,
|
||||
(u.first_name || ' ' || u.last_name) as requester_name
|
||||
FROM requests r
|
||||
JOIN request_types rt ON rt.id = r.request_type_id
|
||||
JOIN users u ON u.id = r.requester_id
|
||||
WHERE r.deleted_at IS NULL
|
||||
AND r.status::text = ANY($3::text[])
|
||||
AND ST_DWithin(
|
||||
r.location,
|
||||
ST_SetSRID(ST_MakePoint($1, $2), 4326)::geography,
|
||||
$4
|
||||
)
|
||||
ORDER BY distance_meters
|
||||
LIMIT $5 OFFSET $6;
|
||||
|
||||
-- ============================================================================
|
||||
-- Поиск заявок в прямоугольной области (для карты)
|
||||
-- ============================================================================
|
||||
|
||||
-- name: FindRequestsInBounds :many
|
||||
SELECT
|
||||
r.id,
|
||||
r.title,
|
||||
r.urgency,
|
||||
r.status,
|
||||
r.created_at,
|
||||
ST_Y(r.location::geometry) as latitude,
|
||||
ST_X(r.location::geometry) as longitude,
|
||||
rt.icon as request_type_icon,
|
||||
rt.name as request_type_name
|
||||
FROM requests r
|
||||
JOIN request_types rt ON rt.id = r.request_type_id
|
||||
WHERE r.deleted_at IS NULL
|
||||
AND r.status::text = ANY($1::text[])
|
||||
AND ST_Within(
|
||||
r.location::geometry,
|
||||
ST_MakeEnvelope($2, $3, $4, $5, 4326)
|
||||
)
|
||||
ORDER BY r.created_at DESC
|
||||
LIMIT 200;
|
||||
|
||||
-- ============================================================================
|
||||
-- Подсчет заявок поблизости
|
||||
-- ============================================================================
|
||||
|
||||
-- name: CountRequestsNearby :one
|
||||
SELECT COUNT(*) FROM requests r
|
||||
WHERE r.deleted_at IS NULL
|
||||
AND r.status = $3
|
||||
AND ST_DWithin(
|
||||
r.location,
|
||||
ST_SetSRID(ST_MakePoint($1, $2), 4326)::geography,
|
||||
$4
|
||||
);
|
||||
|
||||
-- ============================================================================
|
||||
-- Поиск волонтеров рядом с заявкой
|
||||
-- ============================================================================
|
||||
|
||||
-- name: FindVolunteersNearRequest :many
|
||||
SELECT
|
||||
u.id,
|
||||
(u.first_name || ' ' || u.last_name) as full_name,
|
||||
u.avatar_url,
|
||||
u.volunteer_rating,
|
||||
u.completed_requests_count,
|
||||
ST_Y(u.location::geometry) as latitude,
|
||||
ST_X(u.location::geometry) as longitude,
|
||||
ST_Distance(
|
||||
u.location,
|
||||
(SELECT req.location FROM requests req WHERE req.id = $1)
|
||||
) as distance_meters
|
||||
FROM users u
|
||||
JOIN user_roles ur ON ur.user_id = u.id
|
||||
JOIN roles r ON r.id = ur.role_id
|
||||
WHERE r.name = 'volunteer'
|
||||
AND u.deleted_at IS NULL
|
||||
AND u.is_blocked = FALSE
|
||||
AND u.location IS NOT NULL
|
||||
AND ST_DWithin(
|
||||
u.location,
|
||||
(SELECT req.location FROM requests req WHERE req.id = $1),
|
||||
$2
|
||||
)
|
||||
ORDER BY distance_meters
|
||||
LIMIT $3;
|
||||
|
||||
-- ============================================================================
|
||||
-- Поиск ближайших заявок для волонтера
|
||||
-- ============================================================================
|
||||
|
||||
-- name: FindNearestRequestsForVolunteer :many
|
||||
SELECT
|
||||
r.id,
|
||||
r.title,
|
||||
r.description,
|
||||
r.urgency,
|
||||
r.status,
|
||||
r.created_at,
|
||||
ST_Y(r.location::geometry) as latitude,
|
||||
ST_X(r.location::geometry) as longitude,
|
||||
ST_Distance(
|
||||
r.location,
|
||||
(SELECT u.location FROM users u WHERE u.id = $1)
|
||||
) as distance_meters,
|
||||
rt.name as request_type_name,
|
||||
rt.icon as request_type_icon
|
||||
FROM requests r
|
||||
JOIN request_types rt ON rt.id = r.request_type_id
|
||||
WHERE r.deleted_at IS NULL
|
||||
AND r.status = 'approved'
|
||||
AND r.assigned_volunteer_id IS NULL
|
||||
AND ST_DWithin(
|
||||
r.location,
|
||||
(SELECT u.location FROM users u WHERE u.id = $1),
|
||||
$2
|
||||
)
|
||||
ORDER BY
|
||||
CASE r.urgency
|
||||
WHEN 'urgent' THEN 1
|
||||
WHEN 'high' THEN 2
|
||||
WHEN 'medium' THEN 3
|
||||
ELSE 4
|
||||
END,
|
||||
distance_meters
|
||||
LIMIT $3;
|
||||
102
internal/database/queries/rbac.sql
Normal file
102
internal/database/queries/rbac.sql
Normal file
@@ -0,0 +1,102 @@
|
||||
-- Фаза 1B: RBAC (Role-Based Access Control) (КРИТИЧНО)
|
||||
-- Запросы для управления ролями и правами доступа
|
||||
|
||||
-- ============================================================================
|
||||
-- Роли
|
||||
-- ============================================================================
|
||||
|
||||
-- name: GetRoleByName :one
|
||||
SELECT * FROM roles
|
||||
WHERE name = $1;
|
||||
|
||||
-- name: GetRoleByID :one
|
||||
SELECT * FROM roles
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: ListAllRoles :many
|
||||
SELECT * FROM roles
|
||||
ORDER BY name;
|
||||
|
||||
-- ============================================================================
|
||||
-- Пользовательские роли
|
||||
-- ============================================================================
|
||||
|
||||
-- name: GetUserRoles :many
|
||||
SELECT r.* FROM roles r
|
||||
JOIN user_roles ur ON ur.role_id = r.id
|
||||
WHERE ur.user_id = $1
|
||||
ORDER BY r.name;
|
||||
|
||||
-- name: AssignRoleToUser :one
|
||||
INSERT INTO user_roles (user_id, role_id, assigned_by)
|
||||
VALUES ($1, $2, $3)
|
||||
ON CONFLICT (user_id, role_id) DO NOTHING
|
||||
RETURNING *;
|
||||
|
||||
-- name: RemoveRoleFromUser :exec
|
||||
DELETE FROM user_roles
|
||||
WHERE user_id = $1 AND role_id = $2;
|
||||
|
||||
-- name: UserHasRole :one
|
||||
SELECT EXISTS(
|
||||
SELECT 1 FROM user_roles
|
||||
WHERE user_id = $1 AND role_id = $2
|
||||
);
|
||||
|
||||
-- name: UserHasRoleByName :one
|
||||
SELECT EXISTS(
|
||||
SELECT 1 FROM user_roles ur
|
||||
JOIN roles r ON r.id = ur.role_id
|
||||
WHERE ur.user_id = $1 AND r.name = $2
|
||||
);
|
||||
|
||||
-- ============================================================================
|
||||
-- Права доступа
|
||||
-- ============================================================================
|
||||
|
||||
-- name: GetUserPermissions :many
|
||||
SELECT DISTINCT p.name, p.resource, p.action, p.description
|
||||
FROM users u
|
||||
JOIN user_roles ur ON ur.user_id = u.id
|
||||
JOIN role_permissions rp ON rp.role_id = ur.role_id
|
||||
JOIN permissions p ON p.id = rp.permission_id
|
||||
WHERE u.id = $1
|
||||
AND u.deleted_at IS NULL
|
||||
AND u.is_blocked = FALSE
|
||||
ORDER BY p.resource, p.action;
|
||||
|
||||
-- name: GetPermissionByName :one
|
||||
SELECT * FROM permissions
|
||||
WHERE name = $1;
|
||||
|
||||
-- name: ListPermissionsByRole :many
|
||||
SELECT p.* FROM permissions p
|
||||
JOIN role_permissions rp ON rp.permission_id = p.id
|
||||
WHERE rp.role_id = $1
|
||||
ORDER BY p.resource, p.action;
|
||||
|
||||
-- name: UserHasPermission :one
|
||||
SELECT EXISTS(
|
||||
SELECT 1
|
||||
FROM users u
|
||||
JOIN user_roles ur ON ur.user_id = u.id
|
||||
JOIN role_permissions rp ON rp.role_id = ur.role_id
|
||||
JOIN permissions p ON p.id = rp.permission_id
|
||||
WHERE u.id = $1
|
||||
AND p.name = $2
|
||||
AND u.deleted_at IS NULL
|
||||
AND u.is_blocked = FALSE
|
||||
);
|
||||
|
||||
-- name: UserHasAnyPermission :one
|
||||
SELECT EXISTS(
|
||||
SELECT 1
|
||||
FROM users u
|
||||
JOIN user_roles ur ON ur.user_id = u.id
|
||||
JOIN role_permissions rp ON rp.role_id = ur.role_id
|
||||
JOIN permissions p ON p.id = rp.permission_id
|
||||
WHERE u.id = $1
|
||||
AND p.name = ANY($2::varchar[])
|
||||
AND u.deleted_at IS NULL
|
||||
AND u.is_blocked = FALSE
|
||||
);
|
||||
339
internal/database/queries/requests.sql
Normal file
339
internal/database/queries/requests.sql
Normal file
@@ -0,0 +1,339 @@
|
||||
-- Фаза 2A: Управление заявками (ВЫСОКИЙ ПРИОРИТЕТ)
|
||||
-- CRUD операции для заявок на помощь
|
||||
|
||||
-- ============================================================================
|
||||
-- Создание и получение заявок
|
||||
-- ============================================================================
|
||||
|
||||
-- name: CreateRequest :one
|
||||
INSERT INTO requests (
|
||||
requester_id,
|
||||
request_type_id,
|
||||
title,
|
||||
description,
|
||||
location,
|
||||
address,
|
||||
city,
|
||||
desired_completion_date,
|
||||
urgency,
|
||||
contact_phone,
|
||||
contact_notes
|
||||
) VALUES (
|
||||
$1,
|
||||
$2,
|
||||
$3,
|
||||
$4,
|
||||
ST_SetSRID(ST_MakePoint($5, $6), 4326)::geography,
|
||||
$7,
|
||||
$8,
|
||||
$9,
|
||||
$10,
|
||||
$11,
|
||||
$12
|
||||
) RETURNING
|
||||
id,
|
||||
requester_id,
|
||||
request_type_id,
|
||||
title,
|
||||
description,
|
||||
ST_Y(location::geometry) as latitude,
|
||||
ST_X(location::geometry) as longitude,
|
||||
address,
|
||||
city,
|
||||
desired_completion_date,
|
||||
urgency,
|
||||
contact_phone,
|
||||
contact_notes,
|
||||
status,
|
||||
assigned_volunteer_id,
|
||||
created_at,
|
||||
updated_at,
|
||||
deleted_at;
|
||||
|
||||
-- name: GetRequestByID :one
|
||||
SELECT
|
||||
r.id,
|
||||
r.requester_id,
|
||||
r.request_type_id,
|
||||
r.title,
|
||||
r.description,
|
||||
ST_Y(r.location::geometry) as latitude,
|
||||
ST_X(r.location::geometry) as longitude,
|
||||
r.address,
|
||||
r.city,
|
||||
r.desired_completion_date,
|
||||
r.urgency,
|
||||
r.contact_phone,
|
||||
r.contact_notes,
|
||||
r.status,
|
||||
r.assigned_volunteer_id,
|
||||
r.created_at,
|
||||
r.updated_at,
|
||||
r.deleted_at,
|
||||
r.completed_at,
|
||||
rt.name as request_type_name,
|
||||
rt.icon as request_type_icon,
|
||||
(u.first_name || ' ' || u.last_name) as requester_name,
|
||||
u.phone as requester_phone,
|
||||
u.email as requester_email,
|
||||
(av.first_name || ' ' || av.last_name) as assigned_volunteer_name,
|
||||
av.phone as assigned_volunteer_phone
|
||||
FROM requests r
|
||||
JOIN request_types rt ON rt.id = r.request_type_id
|
||||
JOIN users u ON u.id = r.requester_id
|
||||
LEFT JOIN users av ON av.id = r.assigned_volunteer_id
|
||||
WHERE r.id = $1 AND r.deleted_at IS NULL;
|
||||
|
||||
-- name: GetRequestsByRequester :many
|
||||
SELECT
|
||||
r.id,
|
||||
r.requester_id,
|
||||
r.request_type_id,
|
||||
r.title,
|
||||
r.description,
|
||||
ST_Y(r.location::geometry) as latitude,
|
||||
ST_X(r.location::geometry) as longitude,
|
||||
r.address,
|
||||
r.city,
|
||||
r.desired_completion_date,
|
||||
r.urgency,
|
||||
r.contact_phone,
|
||||
r.contact_notes,
|
||||
r.status,
|
||||
r.assigned_volunteer_id,
|
||||
r.created_at,
|
||||
r.updated_at,
|
||||
r.deleted_at,
|
||||
rt.name as request_type_name,
|
||||
rt.icon as request_type_icon
|
||||
FROM requests r
|
||||
JOIN request_types rt ON rt.id = r.request_type_id
|
||||
WHERE r.requester_id = $1
|
||||
AND r.deleted_at IS NULL
|
||||
ORDER BY r.created_at DESC
|
||||
LIMIT $2 OFFSET $3;
|
||||
|
||||
-- name: GetRequestsByStatus :many
|
||||
SELECT
|
||||
r.id,
|
||||
r.requester_id,
|
||||
r.request_type_id,
|
||||
r.title,
|
||||
r.description,
|
||||
ST_Y(r.location::geometry) as latitude,
|
||||
ST_X(r.location::geometry) as longitude,
|
||||
r.address,
|
||||
r.city,
|
||||
r.desired_completion_date,
|
||||
r.urgency,
|
||||
r.contact_phone,
|
||||
r.contact_notes,
|
||||
r.status,
|
||||
r.assigned_volunteer_id,
|
||||
r.created_at,
|
||||
r.updated_at,
|
||||
r.deleted_at,
|
||||
rt.name as request_type_name,
|
||||
(u.first_name || ' ' || u.last_name) as requester_name
|
||||
FROM requests r
|
||||
JOIN request_types rt ON rt.id = r.request_type_id
|
||||
JOIN users u ON u.id = r.requester_id
|
||||
WHERE r.status = $1
|
||||
AND r.deleted_at IS NULL
|
||||
ORDER BY r.created_at DESC
|
||||
LIMIT $2 OFFSET $3;
|
||||
|
||||
-- ============================================================================
|
||||
-- Обновление заявок
|
||||
-- ============================================================================
|
||||
|
||||
-- name: UpdateRequestStatus :exec
|
||||
UPDATE requests SET
|
||||
status = $2,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- name: AssignVolunteerToRequest :exec
|
||||
UPDATE requests SET
|
||||
assigned_volunteer_id = $2,
|
||||
status = 'in_progress',
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- name: CompleteRequest :exec
|
||||
UPDATE requests SET
|
||||
status = 'completed',
|
||||
completed_at = CURRENT_TIMESTAMP,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- name: CancelRequest :exec
|
||||
UPDATE requests SET
|
||||
status = 'cancelled',
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- name: ModerateRequest :exec
|
||||
UPDATE requests SET
|
||||
status = $2,
|
||||
moderated_by = $3,
|
||||
moderated_at = CURRENT_TIMESTAMP,
|
||||
moderation_comment = $4,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- ============================================================================
|
||||
-- Удаление заявок
|
||||
-- ============================================================================
|
||||
|
||||
-- name: DeleteRequest :exec
|
||||
UPDATE requests SET
|
||||
deleted_at = CURRENT_TIMESTAMP,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1
|
||||
AND requester_id = $2
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- ============================================================================
|
||||
-- Типы заявок
|
||||
-- ============================================================================
|
||||
|
||||
-- name: ListRequestTypes :many
|
||||
SELECT * FROM request_types
|
||||
WHERE is_active = TRUE
|
||||
ORDER BY name;
|
||||
|
||||
-- name: GetRequestTypeByID :one
|
||||
SELECT * FROM request_types
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: GetRequestTypeByName :one
|
||||
SELECT * FROM request_types
|
||||
WHERE name = $1;
|
||||
|
||||
-- ============================================================================
|
||||
-- Статистика
|
||||
-- ============================================================================
|
||||
|
||||
-- name: CountRequestsByRequester :one
|
||||
SELECT COUNT(*) FROM requests
|
||||
WHERE requester_id = $1
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- name: CountRequestsByStatus :one
|
||||
SELECT COUNT(*) FROM requests
|
||||
WHERE status = $1
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- ============================================================================
|
||||
-- Модерация заявок
|
||||
-- ============================================================================
|
||||
|
||||
-- name: GetPendingModerationRequests :many
|
||||
SELECT
|
||||
r.id,
|
||||
r.requester_id,
|
||||
r.request_type_id,
|
||||
r.title,
|
||||
r.description,
|
||||
ST_Y(r.location::geometry) as latitude,
|
||||
ST_X(r.location::geometry) as longitude,
|
||||
r.address,
|
||||
r.city,
|
||||
r.desired_completion_date,
|
||||
r.urgency,
|
||||
r.contact_phone,
|
||||
r.contact_notes,
|
||||
r.status,
|
||||
r.created_at,
|
||||
r.updated_at,
|
||||
rt.name as request_type_name,
|
||||
rt.icon as request_type_icon,
|
||||
(u.first_name || ' ' || u.last_name) as requester_name,
|
||||
u.email as requester_email,
|
||||
u.phone as requester_phone
|
||||
FROM requests r
|
||||
JOIN request_types rt ON rt.id = r.request_type_id
|
||||
JOIN users u ON u.id = r.requester_id
|
||||
WHERE r.status = 'pending_moderation'
|
||||
AND r.deleted_at IS NULL
|
||||
ORDER BY r.created_at ASC
|
||||
LIMIT $1 OFFSET $2;
|
||||
|
||||
-- name: ApproveRequest :exec
|
||||
UPDATE requests SET
|
||||
status = 'approved',
|
||||
moderated_by = $2,
|
||||
moderated_at = CURRENT_TIMESTAMP,
|
||||
moderation_comment = sqlc.narg('moderation_comment'),
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1
|
||||
AND status = 'pending_moderation'
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- name: RejectRequest :exec
|
||||
UPDATE requests SET
|
||||
status = 'rejected',
|
||||
moderated_by = $2,
|
||||
moderated_at = CURRENT_TIMESTAMP,
|
||||
moderation_comment = $3,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1
|
||||
AND status = 'pending_moderation'
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- name: GetModeratedRequests :many
|
||||
SELECT
|
||||
r.id,
|
||||
r.requester_id,
|
||||
r.request_type_id,
|
||||
r.title,
|
||||
r.description,
|
||||
ST_Y(r.location::geometry) as latitude,
|
||||
ST_X(r.location::geometry) as longitude,
|
||||
r.address,
|
||||
r.status,
|
||||
r.moderated_by,
|
||||
r.moderated_at,
|
||||
r.moderation_comment,
|
||||
r.created_at,
|
||||
rt.name as request_type_name,
|
||||
(u.first_name || ' ' || u.last_name) as requester_name,
|
||||
(m.first_name || ' ' || m.last_name) as moderator_name
|
||||
FROM requests r
|
||||
JOIN request_types rt ON rt.id = r.request_type_id
|
||||
JOIN users u ON u.id = r.requester_id
|
||||
LEFT JOIN users m ON m.id = r.moderated_by
|
||||
WHERE r.moderated_by = $1
|
||||
AND r.deleted_at IS NULL
|
||||
ORDER BY r.moderated_at DESC
|
||||
LIMIT $2 OFFSET $3;
|
||||
|
||||
-- ============================================================================
|
||||
-- Аудит действий модераторов
|
||||
-- ============================================================================
|
||||
|
||||
-- name: GetModeratorActionsByRequest :many
|
||||
SELECT
|
||||
ma.*,
|
||||
(u.first_name || ' ' || u.last_name) as moderator_name,
|
||||
u.email as moderator_email
|
||||
FROM moderator_actions ma
|
||||
JOIN users u ON u.id = ma.moderator_id
|
||||
WHERE ma.target_request_id = $1
|
||||
ORDER BY ma.created_at DESC;
|
||||
|
||||
-- name: GetModeratorActionsByModerator :many
|
||||
SELECT
|
||||
ma.*,
|
||||
r.title as request_title,
|
||||
r.status as request_status
|
||||
FROM moderator_actions ma
|
||||
LEFT JOIN requests r ON r.id = ma.target_request_id
|
||||
WHERE ma.moderator_id = $1
|
||||
ORDER BY ma.created_at DESC
|
||||
LIMIT $2 OFFSET $3;
|
||||
192
internal/database/queries/responses.sql
Normal file
192
internal/database/queries/responses.sql
Normal file
@@ -0,0 +1,192 @@
|
||||
-- Фаза 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);
|
||||
137
internal/database/queries/users.sql
Normal file
137
internal/database/queries/users.sql
Normal file
@@ -0,0 +1,137 @@
|
||||
-- Фаза 1C: Управление профилем (КРИТИЧНО)
|
||||
-- Запросы для получения и обновления профилей пользователей
|
||||
|
||||
-- ============================================================================
|
||||
-- Профиль пользователя
|
||||
-- ============================================================================
|
||||
|
||||
-- name: GetUserProfile :one
|
||||
SELECT
|
||||
id,
|
||||
email,
|
||||
phone,
|
||||
first_name,
|
||||
last_name,
|
||||
avatar_url,
|
||||
ST_Y(location::geometry) as latitude,
|
||||
ST_X(location::geometry) as longitude,
|
||||
address,
|
||||
city,
|
||||
volunteer_rating,
|
||||
completed_requests_count,
|
||||
is_verified,
|
||||
is_blocked,
|
||||
email_verified,
|
||||
created_at,
|
||||
updated_at,
|
||||
last_login_at
|
||||
FROM users
|
||||
WHERE id = $1 AND deleted_at IS NULL;
|
||||
|
||||
-- name: UpdateUserProfile :exec
|
||||
UPDATE users SET
|
||||
phone = COALESCE(sqlc.narg('phone'), phone),
|
||||
first_name = COALESCE(sqlc.narg('first_name'), first_name),
|
||||
last_name = COALESCE(sqlc.narg('last_name'), last_name),
|
||||
avatar_url = COALESCE(sqlc.narg('avatar_url'), avatar_url),
|
||||
address = COALESCE(sqlc.narg('address'), address),
|
||||
city = COALESCE(sqlc.narg('city'), city),
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = sqlc.arg('user_id');
|
||||
|
||||
-- name: UpdateUserLocation :exec
|
||||
UPDATE users SET
|
||||
location = ST_SetSRID(ST_MakePoint($2, $3), 4326)::geography,
|
||||
address = COALESCE(sqlc.narg('address'), address),
|
||||
city = COALESCE(sqlc.narg('city'), city),
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: VerifyUserEmail :exec
|
||||
UPDATE users SET
|
||||
email_verified = TRUE,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: UpdateUserPassword :exec
|
||||
UPDATE users SET
|
||||
password_hash = $2,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: BlockUser :exec
|
||||
UPDATE users SET
|
||||
is_blocked = TRUE,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: UnblockUser :exec
|
||||
UPDATE users SET
|
||||
is_blocked = FALSE,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: SoftDeleteUser :exec
|
||||
UPDATE users SET
|
||||
deleted_at = CURRENT_TIMESTAMP,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = $1;
|
||||
|
||||
-- ============================================================================
|
||||
-- Поиск пользователей
|
||||
-- ============================================================================
|
||||
|
||||
-- name: GetUsersByIDs :many
|
||||
SELECT
|
||||
id,
|
||||
email,
|
||||
phone,
|
||||
password_hash,
|
||||
first_name,
|
||||
last_name,
|
||||
avatar_url,
|
||||
ST_Y(location::geometry) as latitude,
|
||||
ST_X(location::geometry) as longitude,
|
||||
address,
|
||||
city,
|
||||
volunteer_rating,
|
||||
completed_requests_count,
|
||||
is_verified,
|
||||
is_blocked,
|
||||
email_verified,
|
||||
created_at,
|
||||
updated_at,
|
||||
last_login_at,
|
||||
deleted_at
|
||||
FROM users
|
||||
WHERE id = ANY($1::bigint[])
|
||||
AND deleted_at IS NULL;
|
||||
|
||||
-- name: SearchUsersByName :many
|
||||
SELECT
|
||||
id,
|
||||
email,
|
||||
first_name,
|
||||
last_name,
|
||||
avatar_url,
|
||||
volunteer_rating,
|
||||
completed_requests_count,
|
||||
is_verified
|
||||
FROM users
|
||||
WHERE (first_name ILIKE '%' || $1 || '%' OR last_name ILIKE '%' || $1 || '%' OR (first_name || ' ' || last_name) ILIKE '%' || $1 || '%')
|
||||
AND deleted_at IS NULL
|
||||
AND is_blocked = FALSE
|
||||
ORDER BY volunteer_rating DESC NULLS LAST
|
||||
LIMIT $2 OFFSET $3;
|
||||
|
||||
-- name: GetVolunteerStatistics :one
|
||||
SELECT
|
||||
id,
|
||||
first_name,
|
||||
last_name,
|
||||
volunteer_rating,
|
||||
completed_requests_count,
|
||||
created_at as member_since
|
||||
FROM users
|
||||
WHERE id = $1
|
||||
AND deleted_at IS NULL;
|
||||
Reference in New Issue
Block a user