97 lines
3.7 KiB
SQL
97 lines
3.7 KiB
SQL
|
|
DELIMITER $$
|
|
|
|
CREATE
|
|
/*[DEFINER = { user | CURRENT_USER }]*/
|
|
PROCEDURE `member_score`(IN courseid INT)
|
|
/*LANGUAGE SQL
|
|
| [NOT] DETERMINISTIC
|
|
| { CONTAINS SQL | NO SQL | READS SQL DATA | MODIFIES SQL DATA }
|
|
| SQL SECURITY { DEFINER | INVOKER }
|
|
| COMMENT 'string'*/
|
|
BEGIN
|
|
|
|
CREATE TEMPORARY TABLE IF NOT EXISTS course_teachers (
|
|
id INT
|
|
|
|
);
|
|
TRUNCATE TABLE course_teachers;
|
|
|
|
CREATE TEMPORARY TABLE IF NOT EXISTS mems (
|
|
id INT ,
|
|
user_id INT,
|
|
course_id INT,
|
|
created_on DATETIME,
|
|
course_group_id INT,
|
|
score FLOAT DEFAULT 0
|
|
);
|
|
TRUNCATE TABLE mems;
|
|
|
|
CREATE TEMPORARY TABLE IF NOT EXISTS mem_home (
|
|
id INT,
|
|
user_id INT,
|
|
course_id INT,
|
|
created_on DATETIME,
|
|
course_group_id INT,
|
|
home_id INT,
|
|
score FLOAT DEFAULT 0
|
|
);
|
|
TRUNCATE TABLE mem_home;
|
|
|
|
CREATE TEMPORARY TABLE IF NOT EXISTS t_scores (
|
|
|
|
home_id INT,
|
|
score FLOAT
|
|
);
|
|
TRUNCATE TABLE t_scores;
|
|
|
|
CREATE TEMPORARY TABLE IF NOT EXISTS s_scores (
|
|
|
|
home_id INT,
|
|
score FLOAT
|
|
);
|
|
TRUNCATE TABLE s_scores;
|
|
|
|
CREATE TEMPORARY TABLE IF NOT EXISTS scores (
|
|
|
|
user_id INT,
|
|
score FLOAT
|
|
);
|
|
TRUNCATE TABLE scores;
|
|
|
|
INSERT INTO course_teachers (SELECT members.user_id FROM members WHERE members.user_id NOT IN (SELECT student_id FROM students_for_courses WHERE course_id = courseid));
|
|
|
|
#查出所有的学生
|
|
|
|
INSERT INTO mems (id, user_id, course_id, created_on, course_group_id)
|
|
(SELECT members.id, members.user_id, members.course_id, members.created_on, members.course_group_id
|
|
FROM members WHERE course_id = courseid AND members.user_id NOT IN (SELECT id FROM course_teachers));
|
|
|
|
# 查出所有的学生列表及其作业
|
|
INSERT INTO mem_home (id, user_id, course_id, created_on, course_group_id,home_id)
|
|
(SELECT members.id, members.user_id, members.course_id, members.created_on, members.course_group_id, homework_attaches.id
|
|
FROM members, homework_attaches WHERE course_id = courseid
|
|
AND members.user_id = homework_attaches.user_id AND members.user_id NOT IN (SELECT id FROM course_teachers)
|
|
AND homework_attaches.bid_id IN (SELECT bid_id FROM homework_for_courses WHERE course_id = courseid ));
|
|
|
|
INSERT INTO t_scores (home_id, score) (SELECT rateable_id,AVG(seems_rateable_rates.stars)
|
|
FROM seems_rateable_rates WHERE rateable_type = 'HomeworkAttach' AND rateable_id IN (SELECT mem_home.home_id FROM mem_home)
|
|
AND rater_id IN (SELECT id FROM course_teachers)
|
|
GROUP BY rateable_id);
|
|
|
|
INSERT INTO s_scores (home_id, score) (SELECT rateable_id,AVG(seems_rateable_rates.stars)
|
|
FROM seems_rateable_rates WHERE rateable_type = 'HomeworkAttach' AND rateable_id IN (SELECT mem_home.home_id FROM mem_home)
|
|
AND rater_id NOT IN (SELECT id FROM course_teachers)
|
|
GROUP BY rateable_id) ;
|
|
|
|
UPDATE mem_home, t_scores SET mem_home.score = t_scores.score WHERE mem_home.home_id = t_scores.home_id ;
|
|
|
|
UPDATE mem_home, s_scores SET mem_home.score = s_scores.score WHERE mem_home.home_id = s_scores.home_id AND mem_home.score = 0;
|
|
|
|
INSERT INTO scores (user_id, score) (SELECT user_id, SUM(score) FROM mem_home GROUP BY user_id);
|
|
UPDATE mems, scores SET mems.score = scores.score WHERE mems.user_id = scores.user_id;
|
|
|
|
SELECT * FROM mems ORDER BY score DESC;
|
|
END$$
|
|
|
|
DELIMITER ; |