350 lines
10 KiB
Ruby
350 lines
10 KiB
Ruby
class StoredStatusProcedure < ActiveRecord::Migration
|
|
def up
|
|
#sql = <<- END_OF_SQL_CODE
|
|
execute "
|
|
create procedure `sp_user_status_cursor`()
|
|
begin
|
|
declare user_uid bigint(22);
|
|
declare user_changesets_count int(10);
|
|
declare _done tinyint(1) default 0;
|
|
declare cur_user cursor for select user_id, count(*) from changesets where user_id != '' group by user_id;
|
|
declare continue handler for not found set _done = 1;
|
|
open cur_user;
|
|
loop_xxx:loop
|
|
fetch cur_user into user_uid,user_changesets_count;
|
|
if _done=1 then
|
|
leave loop_xxx;
|
|
end if;
|
|
begin
|
|
declare journals_for_messages_count int(10);
|
|
declare journals_count int(10);
|
|
declare comments_count int(10);
|
|
declare messages_count int(10);
|
|
declare news_count int(10);
|
|
declare wiki_contents_count int(10);
|
|
declare activities_count int(10);
|
|
declare total_count numeric(8,2);
|
|
|
|
select count(*) into journals_for_messages_count from journals_for_messages where user_id = user_uid;
|
|
select count(*) into journals_count from journals where user_id = user_uid;
|
|
select count(*) into comments_count from comments where author_id = user_uid;
|
|
select count(*) into messages_count from messages where author_id = user_uid;
|
|
select count(*) into news_count from news where author_id = user_uid;
|
|
select count(*) into wiki_contents_count from wiki_contents where author_id = user_uid;
|
|
select count(*) into activities_count from activities where user_id = user_uid;
|
|
|
|
set total_count = journals_for_messages_count*0.05 +
|
|
journals_count*0.1 +
|
|
comments_count*0.1 +
|
|
messages_count*0.05 +
|
|
news_count*0.1 +
|
|
wiki_contents_count*0.1 +
|
|
activities_count*0.2 +
|
|
user_changesets_count*0.3;
|
|
|
|
update user_statuses set changesets_count = user_changesets_count, grade = total_count where user_id = user_uid;
|
|
commit;
|
|
end;
|
|
end loop;
|
|
end;
|
|
"
|
|
execute "
|
|
create event if not exists e_test
|
|
on schedule every 1 day starts'2013-08-27 01:50:00'
|
|
on completion preserve
|
|
do call `sp_user_status_cursor`();
|
|
"
|
|
execute "
|
|
CREATE PROCEDURE `sp_project_status_cursor` ()
|
|
BEGIN
|
|
DECLARE project_uid bigint(22);
|
|
DECLARE project_changesets_count int(10);
|
|
DECLARE _done tinyint(1) DEFAULT 0;
|
|
|
|
DECLARE cur_project CURSOR FOR
|
|
SELECT
|
|
project_id,
|
|
COUNT(*)
|
|
FROM (SELECT
|
|
project_id,
|
|
repositories.id
|
|
FROM repositories
|
|
INNER JOIN changesets
|
|
WHERE repositories.id = changesets.repository_id
|
|
AND project_id IN (SELECT
|
|
projects.id
|
|
FROM projects
|
|
WHERE (((projects.status <> 9)
|
|
AND (projects.is_public = 1))))) t
|
|
GROUP BY project_id;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET _done = 1;
|
|
OPEN cur_project;
|
|
loop_xxx:
|
|
LOOP
|
|
FETCH cur_project INTO project_uid, project_changesets_count;
|
|
IF _done = 1 THEN
|
|
LEAVE loop_xxx;
|
|
END IF;
|
|
|
|
BEGIN
|
|
DECLARE total_count numeric(8, 2);
|
|
DECLARE news_id int(10);
|
|
DECLARE issues_id int(10);
|
|
DECLARE issues_count int(10);
|
|
DECLARE news_count int(10);
|
|
DECLARE time_entries_count int(10);
|
|
DECLARE documents_count int(10);
|
|
DECLARE issues_jour_count_total int(10) DEFAULT 0;
|
|
DECLARE issues_jour_count int(10);
|
|
DECLARE news_jour_count_total int(10) DEFAULT 0;
|
|
DECLARE news_jour_count int(10);
|
|
DECLARE boards_messages_count int(10);
|
|
|
|
DECLARE cur_user_id int(10);
|
|
DECLARE cur_user_issues_journals_count int(10);
|
|
DECLARE cur_user_news_journals_count int(10);
|
|
DECLARE cur_user_issues_count int(10);
|
|
DECLARE cur_user_news_count int(10);
|
|
DECLARE cur_user_issues_id int(10);
|
|
DECLARE cur_user_news_id int(10);
|
|
|
|
|
|
|
|
|
|
DECLARE _inner_done_one tinyint(1) DEFAULT 0;
|
|
DECLARE cur_issues CURSOR FOR
|
|
SELECT
|
|
issues.id
|
|
FROM issues
|
|
WHERE project_id = project_uid;
|
|
DECLARE cur_news CURSOR FOR
|
|
SELECT
|
|
news.id
|
|
FROM news
|
|
WHERE project_id = project_uid;
|
|
DECLARE cur_user CURSOR FOR
|
|
SELECT
|
|
members.user_id
|
|
FROM members
|
|
INNER JOIN users
|
|
ON members.user_id = users.id
|
|
WHERE members.project_id = project_uid
|
|
AND (users.type = 'User' AND users.status = 1);
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET _inner_done_one = 1;
|
|
|
|
OPEN cur_issues;
|
|
loop_issues:
|
|
LOOP
|
|
FETCH cur_issues INTO issues_id;
|
|
IF _inner_done_one = 1 THEN
|
|
LEAVE loop_issues;
|
|
END IF;
|
|
|
|
BEGIN
|
|
SELECT
|
|
COUNT(*) INTO issues_jour_count
|
|
FROM `journals`
|
|
WHERE `journals`.`journalized_id` = issues_id AND `journals`.`journalized_type` = 'Issue';
|
|
SET issues_jour_count_total = issues_jour_count_total + issues_jour_count;
|
|
END;
|
|
END LOOP;
|
|
-- CLOSE cur_issues;
|
|
|
|
SET _inner_done_one = 0;
|
|
|
|
OPEN cur_news;
|
|
loop_news:
|
|
LOOP
|
|
FETCH cur_news INTO news_id;
|
|
IF _inner_done_one = 1 THEN
|
|
LEAVE loop_news;
|
|
END IF;
|
|
|
|
BEGIN
|
|
SELECT
|
|
COUNT(*) INTO news_jour_count
|
|
FROM `journals`
|
|
WHERE `journals`.`journalized_id` = news_id AND `journals`.`journalized_type` = 'News';
|
|
SET news_jour_count_total = news_jour_count_total + news_jour_count;
|
|
END;
|
|
END LOOP;
|
|
-- CLOSE cur_news;
|
|
|
|
SET _inner_done_one = 0;
|
|
|
|
OPEN cur_user;
|
|
loop_user:
|
|
LOOP
|
|
FETCH cur_user INTO cur_user_id;
|
|
IF _inner_done_one = 1 THEN
|
|
LEAVE loop_user;
|
|
END IF;
|
|
|
|
BEGIN
|
|
DECLARE total_cur_user_issues_journals_count int(10) DEFAULT 0;
|
|
DECLARE total_cur_user_news_journals_count int(10) DEFAULT 0;
|
|
DECLARE cur_user_changesets_count INT(10);
|
|
DECLARE user_total_count numeric(8, 2);
|
|
DECLARE _inner_inner_done tinyint(1) DEFAULT 0;
|
|
DECLARE cur_user_issues CURSOR FOR
|
|
SELECT
|
|
issues.id
|
|
FROM issues
|
|
WHERE project_id = project_uid AND author_id = cur_user_id;
|
|
DECLARE cur_user_news CURSOR FOR
|
|
SELECT
|
|
news.id
|
|
FROM news
|
|
WHERE project_id = project_uid AND author_id = cur_user_id;
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET _inner_inner_done = 1;
|
|
|
|
OPEN cur_user_issues;
|
|
loop_user_issues:
|
|
LOOP
|
|
FETCH cur_issues INTO cur_user_issues_id;
|
|
IF _inner_inner_done = 1 THEN
|
|
LEAVE loop_user_issues;
|
|
END IF;
|
|
|
|
BEGIN
|
|
SELECT
|
|
COUNT(*) INTO cur_user_issues_journals_count
|
|
FROM journals
|
|
WHERE journalized_id = cur_user_issues_id AND user_id = cur_user_id
|
|
AND journalized_type = 'Issues';
|
|
SET total_cur_user_issues_journals_count = total_cur_user_issues_journals_count +
|
|
cur_user_issues_journals_count;
|
|
END;
|
|
END LOOP;
|
|
|
|
-- CLOSE cur_user_issues;
|
|
|
|
SET _inner_inner_done = 0;
|
|
|
|
OPEN cur_user_news;
|
|
loop_user_news:
|
|
LOOP
|
|
FETCH cur_user_news INTO cur_user_news_id;
|
|
IF _inner_inner_done = 1 THEN
|
|
LEAVE loop_user_news;
|
|
END IF;
|
|
|
|
BEGIN
|
|
SELECT
|
|
COUNT(*) INTO cur_user_news_journals_count
|
|
FROM journals
|
|
WHERE journalized_id = cur_user_news_id AND user_id = cur_user_id AND journalized_type = 'News';
|
|
SET total_cur_user_news_journals_count = total_cur_user_news_journals_count +
|
|
cur_user_news_journals_count;
|
|
END;
|
|
END LOOP;
|
|
|
|
SELECT
|
|
COUNT(*) INTO cur_user_issues_count
|
|
FROM issues
|
|
WHERE project_id = project_uid AND author_id = cur_user_id;
|
|
SELECT
|
|
COUNT(*) INTO cur_user_news_count
|
|
FROM news
|
|
WHERE project_id = project_uid AND author_id = cur_user_id;
|
|
SELECT
|
|
COUNT(*) INTO cur_user_changesets_count
|
|
FROM changesets
|
|
WHERE user_id = cur_user_id AND
|
|
repository_id IN (SELECT
|
|
id
|
|
FROM repositories
|
|
WHERE project_id = project_uid);
|
|
SET user_total_count = cur_user_issues_count*0.2 +
|
|
cur_user_news_count*0.2 +
|
|
total_cur_user_issues_journals_count*0.1 +
|
|
total_cur_user_news_journals_count*0.1 +
|
|
cur_user_changesets_count*0.4;
|
|
UPDATE user_grades
|
|
SET grade = user_total_count
|
|
WHERE user_id = cur_user_id AND project_id = project_uid;
|
|
COMMIT;
|
|
END;
|
|
END LOOP;
|
|
|
|
SELECT
|
|
COUNT(*) INTO issues_count
|
|
FROM issues
|
|
WHERE project_id = project_uid;
|
|
SELECT
|
|
COUNT(*) INTO news_count
|
|
FROM news
|
|
WHERE project_id = project_uid;
|
|
SELECT
|
|
COUNT(*) INTO documents_count
|
|
FROM documents
|
|
WHERE project_id = project_uid;
|
|
SELECT
|
|
SUM(boards.messages_count) INTO boards_messages_count
|
|
FROM boards
|
|
WHERE project_id = project_uid;
|
|
|
|
IF boards_messages_count IS NULL THEN
|
|
SET boards_messages_count = 0;
|
|
SET total_count = issues_count * 0.2 +
|
|
issues_jour_count_total * 0.1 +
|
|
news_count * 0.1 +
|
|
news_jour_count_total * 0.1 +
|
|
documents_count * 0.1 +
|
|
project_changesets_count * 0.3 +
|
|
boards_messages_count * 0.1;
|
|
ELSE
|
|
SET total_count = issues_count * 0.2 +
|
|
issues_jour_count_total * 0.1 +
|
|
news_count * 0.1 +
|
|
news_jour_count_total * 0.1 +
|
|
documents_count * 0.1 +
|
|
project_changesets_count * 0.3 +
|
|
boards_messages_count * 0.1;
|
|
END IF;
|
|
|
|
IF total_count IS NOT NULL THEN
|
|
|
|
UPDATE project_statuses
|
|
SET changesets_count = project_changesets_count,
|
|
grade = total_count
|
|
WHERE project_id = project_uid;
|
|
ELSE
|
|
UPDATE project_statuses
|
|
SET changesets_count = project_changesets_count,
|
|
grade = 0
|
|
WHERE project_id = project_uid;
|
|
END IF;
|
|
|
|
COMMIT;
|
|
END;
|
|
END LOOP;
|
|
END;
|
|
"
|
|
execute "
|
|
create event if not exists e_project_status_test
|
|
on schedule every 1 day starts'2013-08-27 01:50:00'
|
|
on completion preserve
|
|
do call `sp_project_status_cursor`();
|
|
"
|
|
execute "
|
|
set global event_scheduler = on;
|
|
"
|
|
end
|
|
|
|
def down
|
|
execute " drop procedure if exists `sp_user_status_cursor`;
|
|
"
|
|
execute "
|
|
drop event if exists e_test;
|
|
"
|
|
execute "
|
|
drop procedure if exists `sp_project_status_cursor`;
|
|
"
|
|
execute "
|
|
drop event if exists e_project_status_test;
|
|
"
|
|
end
|
|
end
|