database ready for scenes

parent 18cfd017
......@@ -327,6 +327,7 @@ CREATE TABLE IF NOT EXISTS `stu_picto` (
`id_stu` int(11) NOT NULL,
`id_pic` int(11) NOT NULL,
`attributes` varchar(1000) COLLATE utf8_unicode_ci DEFAULT NULL COMMENT 'JSON object describing the properties of the picto',
`id_scene` int(11) NOT NULL,
PRIMARY KEY (`id`),
KEY `fk_picto` (`id_pic`),
KEY `id_stu` (`id_stu`)
......@@ -443,7 +444,9 @@ CREATE TABLE IF NOT EXISTS `scene` (
`categories` boolean NULL DEFAULT 0,
`id_sup` int(11) NOT NULL,
`id_stu` int(11) NOT NULL,
PRIMARY KEY (`id`)
PRIMARY KEY (`id`),
FOREIGN KEY (`id_sup`) REFERENCES `supervisor` (`id`),
FOREIGN KEY (`id_stu`) REFERENCES `student` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci AUTO_INCREMENT=1
COMMENT="Scene table information. Every scene is related to some stu_pictos";
......@@ -535,7 +538,8 @@ ALTER TABLE `picto_tag`
--
ALTER TABLE `stu_picto`
ADD CONSTRAINT `fk_picto` FOREIGN KEY (`id_pic`) REFERENCES `picto` (`id`),
ADD CONSTRAINT `stu_picto_ibfk_1` FOREIGN KEY (`id_stu`) REFERENCES `student` (`id`);
ADD CONSTRAINT `stu_picto_ibfk_1` FOREIGN KEY (`id_stu`) REFERENCES `student` (`id`),
ADD CONSTRAINT `stu_picto_scene_fk` FOREIGN KEY (`id_scene`) REFERENCES `scene` (`id`);
--
-- Filtros para la tabla `stu_sup`
......
/*
ALTER TABLE stu_picto DROP FOREIGN KEY stu_picto_scene_fk;
ALTER TABLE stu_picto DROP id_scene;
DROP TABLE scene;
*/
DELIMITER $$
DROP PROCEDURE IF EXISTS scene_adapt $$
CREATE PROCEDURE scene_adapt()
BEGIN
DECLARE _id_stu INT;
DECLARE _id_sup INT;
DECLARE done INT DEFAULT FALSE;
DECLARE LID INT;
DECLARE student CURSOR FOR SELECT id FROM pictodb.student;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
/*SET FOREIGN_KEY_CHECKS = 0;*/
OPEN student;
read_loop: LOOP
FETCH student INTO _id_stu;
IF done THEN
LEAVE read_loop;
END IF;
SELECT `id_sup` INTO _id_sup FROM `stu_sup` WHERE `id_stu` = _id_stu LIMIT 1;
/* FIRST SCENE, ACTIVE, WITH CATEGORIES */
INSERT INTO `scene` (name, active, categories, id_sup, id_stu)
VALUES ('with_categories', 1, 1, _id_sup, _id_stu);
SET LID = LAST_INSERT_ID();
UPDATE `stu_picto`
SET `id_scene` = LID
WHERE `id_stu` = _id_stu
AND attributes->"$.free_category_coord_x" IS NULL
AND attributes->"$.free_category_coord_y" IS NULL;
/* SECOND SCENE, NOT ACTIVE, NO CATEGORIES */
INSERT INTO `scene` (name, active, categories, id_sup, id_stu)
VALUES ('no_categories', 0, 0, _id_sup, _id_stu);
SET LID = LAST_INSERT_ID();
UPDATE `stu_picto`
SET `id_scene` = LID
WHERE `id_stu` = _id_stu
AND attributes->"$.free_category_coord_x" IS NOT NULL
AND attributes->"$.free_category_coord_y" IS NOT NULL;
END LOOP;
CLOSE student;
/*SET FOREIGN_KEY_CHECKS = 1;*/
END $$
DELIMITER ;
CALL scene_adapt();
......@@ -27,10 +27,20 @@ Changes to be performed manually in servers to upgrade
`categories` boolean NULL DEFAULT 0,
`id_sup` int(11) NOT NULL,
`id_stu` int(11) NOT NULL,
PRIMARY KEY (`id`)
PRIMARY KEY (`id`),
FOREIGN KEY (`id_sup`) REFERENCES `supervisor` (`id`),
FOREIGN KEY (`id_stu`) REFERENCES `student` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci AUTO_INCREMENT=1
COMMENT="Scene table information. Every scene is related to some stu_pictos";`
- alter table stu_picto to add new reference to scene
`ALTER TABLE `stu_picto` ADD id_scene int(11) NOT NULL;`
`ALTER TABLE `stu_picto` ADD CONSTRAINT `stu_picto_scene_fk` FOREIGN KEY (`id_scene`) REFERENCES `scene` (`id`);`
(si hay problema al añadir la foreign key, hacer SET FOREIGN_KEY_CHECKS = 0; antes de añadirla y SET FOREIGN_KEY_CHECKS = 1; después)
- load default scenes procedure
`source /vagrant/roles/database/files/scene_adapt.sql`
(already done in dev & pre)
- add arasaac to source table
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or sign in to comment