You can not select more than 25 topics
			Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
		
		
		
		
		
			
		
			
				
					
					
						
							370 lines
						
					
					
						
							9.7 KiB
						
					
					
				
			
		
		
	
	
							370 lines
						
					
					
						
							9.7 KiB
						
					
					
				| 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 
 | |
|     users.id 
 | |
|   FROM users  
 | |
|     WHERE users.type = 'User' AND users.status = 1 AND users.admin = 0;
 | |
|   DECLARE CONTINUE HANDLER FOR NOT FOUND SET _done = 1;
 | |
|   OPEN cur_user;
 | |
| loop_xxx:
 | |
| LOOP
 | |
|   FETCH cur_user INTO user_uid ;
 | |
|   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;
 | |
|     SELECT 
 | |
|       COUNT(*) INTO user_changesets_count
 | |
|     FROM changesets  
 | |
|     WHERE changesets.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
 | |
|         projects.id
 | |
|       FROM projects
 | |
|       WHERE projects.status <> 9
 | |
|       AND projects.is_public = 1 AND projects.project_type = 0 ;
 | |
| 
 | |
|   DECLARE CONTINUE HANDLER FOR NOT FOUND SET _done = 1;
 | |
|   OPEN cur_project;
 | |
| loop_xxx:
 | |
| LOOP
 | |
|   FETCH cur_project INTO project_uid;
 | |
|   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;
 | |
|     SELECT 
 | |
|       COUNT(*) INTO project_changesets_count
 | |
|     FROM `changesets` 
 | |
|       INNER JOIN `repositories` ON `changesets`.`repository_id` = `repositories`.`id` 
 | |
|     WHERE `repositories`.`project_id` = project_uid AND (is_default = 1);
 | |
|    
 | |
|       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;
 | |
|   
 | |
|     
 | |
|     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
 |