zee-solution/docs/query.md

199 lines
5.9 KiB
Markdown

# GUIDE
This document catalogs key data queries using a standardized format. Each entry details the query's purpose, core logic, related database objects, full SQL code, important notes, and parameters (if applicable). The goal is to ensure clarity, facilitate understanding, and simplify usage and maintenance.
# FORMAT
## Title:
[Application/Website Name]
app_ver: [app_ver]
doc_ver: [doc_ver]
## [Numerical order].[QUERY NAME]
### Main Functionality
[Briefly describe the core technical function the query performs. E.g., "Fetches unprocessed orders for VIP customers from the last month."]
### Key Logic/Steps
[List or briefly describe the main logical steps the query takes. Focus on complex or critical parts. E.g., 1. Filter VIP customers from the `Customers` table.]
### Related Objects
[List the main tables/views/functions used by the query.]
### Query (`sql` block)
```sql
[Full SQL query code here]
````
### Important Notes/Performance
[Note only particularly important points regarding logic, data, or performance issues/considerations]
### Parameters (if any)
- [Parameter Name] : [Data Type] - [Brief description of the parameter's role]
---
# CONTENT
## Title: ZEE Quiz Application
app_ver: 1.0.0
doc_ver: A1
## 1. User Authentication
### Main Functionality
Verifies user credentials and retrieves user profile data for authentication
### Key Logic/Steps
1. Check if user exists and is active
2. Verify password hash
3. Fetch user roles and permissions
4. Update last login timestamp
### Related Objects
- Tables: users, user_roles, roles, permissions
- Functions: verify_password_hash()
### Query
```sql
WITH user_data AS (
SELECT u.id, u.email, u.password_hash, u.status,
u.last_login_at, u.created_at,
array_agg(DISTINCT r.name) as roles,
array_agg(DISTINCT p.name) as permissions
FROM users u
LEFT JOIN user_roles ur ON u.id = ur.user_id
LEFT JOIN roles r ON ur.role_id = r.id
LEFT JOIN role_permissions rp ON r.id = rp.role_id
LEFT JOIN permissions p ON rp.permission_id = p.id
WHERE u.email = $1
GROUP BY u.id
)
UPDATE users
SET last_login_at = NOW()
FROM user_data
WHERE users.id = user_data.id
RETURNING user_data.*;
```
### Important Notes/Performance
- Uses a CTE for better readability and maintainability
- Indexes required on users(email), user_roles(user_id), role_permissions(role_id)
- Consider caching user permissions for 5 minutes
### Parameters
- $1 : TEXT - User's email address
## 2. Quiz Creation
### Main Functionality
Creates a new quiz with questions and answers
### Key Logic/Steps
1. Begin transaction
2. Insert quiz metadata
3. Insert questions
4. Insert answer options
5. Commit transaction
### Related Objects
- Tables: quizzes, questions, answers
- Triggers: update_quiz_stats
### Query
```sql
WITH new_quiz AS (
INSERT INTO quizzes (
title, description, category_id, creator_id,
time_limit, passing_score, is_public,
created_at, updated_at
) VALUES (
$1, $2, $3, $4, $5, $6, $7,
NOW(), NOW()
) RETURNING id
),
inserted_questions AS (
INSERT INTO questions (
quiz_id, question_text, question_type,
points, order_number
)
SELECT
(SELECT id FROM new_quiz),
q->>'text',
q->>'type',
(q->>'points')::integer,
row_number() OVER ()
FROM json_array_elements($8::json) q
RETURNING id, row_number() OVER ()
)
INSERT INTO answers (
question_id, answer_text, is_correct,
order_number
)
SELECT
q.id,
a->>'text',
(a->>'isCorrect')::boolean,
row_number() OVER (PARTITION BY q.id)
FROM inserted_questions q
CROSS JOIN json_array_elements(
(SELECT q->>'answers'
FROM json_array_elements($8::json) q
OFFSET q.row_number - 1
LIMIT 1
)::json
) a;
```
### Important Notes/Performance
- Transaction ensures data consistency
- JSON input allows flexible question/answer structure
- Trigger updates quiz statistics after question insertion
### Parameters
- $1 : TEXT - Quiz title
- $2 : TEXT - Quiz description
- $3 : UUID - Category ID
- $4 : UUID - Creator's user ID
- $5 : INTEGER - Time limit in minutes
- $6 : INTEGER - Passing score percentage
- $7 : BOOLEAN - Quiz visibility
- $8 : JSON - Questions and answers array
## 3. Quiz Results Analysis
### Main Functionality
Analyzes quiz attempt results and generates performance statistics
### Key Logic/Steps
1. Calculate overall scores
2. Identify correct/incorrect answers
3. Compute time spent per question
4. Generate performance metrics
### Related Objects
- Tables: quiz_attempts, attempt_answers, questions, answers
- Views: quiz_statistics
### Query
```sql
WITH attempt_stats AS (
SELECT
qa.id as attempt_id,
q.id as quiz_id,
q.title as quiz_title,
u.id as user_id,
u.email as user_email,
COUNT(aa.id) as total_questions,
SUM(CASE WHEN aa.answer_id = a.id AND a.is_correct THEN 1 ELSE 0 END) as correct_answers,
AVG(aa.time_spent) as avg_time_per_question,
qa.started_at,
qa.completed_at,
qa.score as final_score
FROM quiz_attempts qa
JOIN quizzes q ON qa.quiz_id = q.id
JOIN users u ON qa.user_id = u.id
JOIN attempt_answers aa ON qa.id = aa.attempt_id
JOIN answers a ON aa.answer_id = a.id
WHERE qa.completed_at >= NOW() - INTERVAL '30 days'
GROUP BY qa.id, q.id, q.title, u.id, u.email
)
SELECT
quiz_id,
quiz_title,
COUNT(DISTINCT user_id) as unique_participants,
AVG(final_score) as average_score,
MIN(final_score) as lowest_score,
MAX(final_score) as highest_score,
AVG(correct_answers::float / total_questions) * 100 as average_accuracy,
AVG(avg_time_per_question) as average_question_time,
AVG(EXTRACT(EPOCH FROM (completed_at - started_at))) as average_completion_time
FROM attempt_stats
GROUP BY quiz_id, quiz_title
ORDER BY average_score DESC;
```
### Important Notes/Performance
- Heavy aggregation query - consider materialized view
- Add indexes on quiz_attempts(completed_at)
- Partitioning by date range for large datasets
### Parameters
None - Query uses fixed 30-day window
---
*Last Updated: 2025-06-06*
*Next Review: 2025-07-01*