1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377
| --------------
START TRANSACTION
--------------
--------------
DROP DATABASE IF EXISTS `base`
--------------
--------------
CREATE DATABASE IF NOT EXISTS `base`
DEFAULT CHARACTER SET `latin1`
DEFAULT COLLATE `latin1_general_ci`
--------------
--------------
DROP TABLE IF EXISTS `fournisseur`
--------------
--------------
CREATE TABLE `fournisseur`
( `num` integer unsigned NOT NULL auto_increment primary key,
`lib` varchar(255) NOT NULL
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_ci`
ROW_FORMAT=COMPRESSED
--------------
--------------
INSERT INTO `fournisseur` (`lib`) values
('Fournisseur Un'),('Fournisseur Deux'),('Fournisseur Trois'),('Fournisseur Quatre'),('Fournisseur Cinq')
--------------
--------------
select * from `fournisseur`
--------------
+-----+--------------------+
| num | lib |
+-----+--------------------+
| 1 | Fournisseur Un |
| 2 | Fournisseur Deux |
| 3 | Fournisseur Trois |
| 4 | Fournisseur Quatre |
| 5 | Fournisseur Cinq |
+-----+--------------------+
--------------
DROP TABLE IF EXISTS `stock`
--------------
--------------
CREATE TABLE `stock`
( `ref` integer unsigned NOT NULL auto_increment primary key,
`description` varchar(255) NOT NULL,
`etat` integer NOT NULL,
`initial` integer NULL default 0,
`date_deb` date NULL default NULL,
`date_fin` date NOT NULL
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_ci`
ROW_FORMAT=COMPRESSED
--------------
--------------
INSERT INTO `stock` (`description`, `etat`,`date_fin`) values
('Stock A',0,'2022-12-31'),('Stock B',0,'2022-12-31'),('Stock C',0,'2022-12-31'),('Stock D',0,'2022-12-31'),('Stock E',0,'2022-12-31')
--------------
--------------
select * from `stock`
--------------
+-----+-------------+------+---------+----------+------------+
| ref | description | etat | initial | date_deb | date_fin |
+-----+-------------+------+---------+----------+------------+
| 1 | Stock A | 0 | 0 | NULL | 2022-12-31 |
| 2 | Stock B | 0 | 0 | NULL | 2022-12-31 |
| 3 | Stock C | 0 | 0 | NULL | 2022-12-31 |
| 4 | Stock D | 0 | 0 | NULL | 2022-12-31 |
| 5 | Stock E | 0 | 0 | NULL | 2022-12-31 |
+-----+-------------+------+---------+----------+------------+
--------------
DROP TABLE IF EXISTS `entree`
--------------
--------------
CREATE TABLE `entree`
( `id` integer unsigned NOT NULL auto_increment primary key,
`ref_fk` integer unsigned NOT NULL,
`num_fk` integer unsigned NOT NULL,
`qte` integer NOT NULL,
`date` date NOT NULL,
CONSTRAINT `FK_01` FOREIGN KEY (`ref_fk`) REFERENCES `stock` (`ref`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `FK_02` FOREIGN KEY (`num_fk`) REFERENCES `fournisseur` (`num`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_ci`
ROW_FORMAT=COMPRESSED
--------------
--------------
DROP TRIGGER IF EXISTS `ajouter`
--------------
--------------
CREATE TRIGGER `ajouter`
BEFORE INSERT ON `entree`
FOR EACH ROW
BEGIN
update `stock` set `etat` = `etat` + NEW.qte where `ref` = NEW.`ref_fk`;
END
--------------
--------------
INSERT INTO `entree` (`ref_fk`,`num_fk`,`qte`,`date`) values
(1,2, 25,'2023-01-01'),(2,3, 50,'2023-01-02'),(3,4, 50,'2023-01-03'),(4,5, 10,'2023-01-04'),(5,1, 40,'2023-01-05'),
(1,3, 10,'2023-01-06'),(2,4, 10,'2023-01-07'),(3,5, 10,'2023-01-08'),(4,1, 40,'2023-01-09'),(5,2, 40,'2023-01-10'),
(1,4, 30,'2023-01-11'),(2,5, 10,'2023-01-12'),(3,1, 20,'2023-01-13'),(4,2, 15,'2023-01-14'),(5,3, 30,'2023-01-15')
--------------
--------------
select * from `entree`
--------------
+----+--------+--------+-----+------------+
| id | ref_fk | num_fk | qte | date |
+----+--------+--------+-----+------------+
| 1 | 1 | 2 | 25 | 2023-01-01 |
| 2 | 2 | 3 | 50 | 2023-01-02 |
| 3 | 3 | 4 | 50 | 2023-01-03 |
| 4 | 4 | 5 | 10 | 2023-01-04 |
| 5 | 5 | 1 | 40 | 2023-01-05 |
| 6 | 1 | 3 | 10 | 2023-01-06 |
| 7 | 2 | 4 | 10 | 2023-01-07 |
| 8 | 3 | 5 | 10 | 2023-01-08 |
| 9 | 4 | 1 | 40 | 2023-01-09 |
| 10 | 5 | 2 | 40 | 2023-01-10 |
| 11 | 1 | 4 | 30 | 2023-01-11 |
| 12 | 2 | 5 | 10 | 2023-01-12 |
| 13 | 3 | 1 | 20 | 2023-01-13 |
| 14 | 4 | 2 | 15 | 2023-01-14 |
| 15 | 5 | 3 | 30 | 2023-01-15 |
+----+--------+--------+-----+------------+
--------------
DROP TABLE IF EXISTS `sortie`
--------------
--------------
CREATE TABLE `sortie`
( `id` integer unsigned NOT NULL auto_increment primary key,
`ref_fk` integer unsigned NOT NULL,
`qte` integer NOT NULL,
`date` date NOT NULL,
CONSTRAINT `FK_03` FOREIGN KEY (`ref_fk`) REFERENCES `stock` (`ref`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_ci`
ROW_FORMAT=COMPRESSED
--------------
--------------
DROP TRIGGER IF EXISTS `retrancher`
--------------
--------------
CREATE TRIGGER `retrancher`
BEFORE INSERT ON `sortie`
FOR EACH ROW
BEGIN
update `stock` set `etat` = `etat` - NEW.qte where `ref` = NEW.`ref_fk`;
END
--------------
--------------
INSERT INTO `sortie` (`ref_fk`,`qte`,`date`) values
(1, 05,'2023-01-06'),(2, 10,'2023-01-09'),(3, 20,'2023-01-10'),(4, 10,'2023-01-12'),(5, 40,'2023-01-15')
--------------
--------------
select * from `sortie`
--------------
+----+--------+-----+------------+
| id | ref_fk | qte | date |
+----+--------+-----+------------+
| 1 | 1 | 5 | 2023-01-06 |
| 2 | 2 | 10 | 2023-01-09 |
| 3 | 3 | 20 | 2023-01-10 |
| 4 | 4 | 10 | 2023-01-12 |
| 5 | 5 | 40 | 2023-01-15 |
+----+--------+-----+------------+
--------------
select * from `stock`
--------------
+-----+-------------+------+---------+----------+------------+
| ref | description | etat | initial | date_deb | date_fin |
+-----+-------------+------+---------+----------+------------+
| 1 | Stock A | 60 | 0 | NULL | 2022-12-31 |
| 2 | Stock B | 60 | 0 | NULL | 2022-12-31 |
| 3 | Stock C | 60 | 0 | NULL | 2022-12-31 |
| 4 | Stock D | 55 | 0 | NULL | 2022-12-31 |
| 5 | Stock E | 70 | 0 | NULL | 2022-12-31 |
+-----+-------------+------+---------+----------+------------+
--------------
update `stock` set `date_deb` = `date_fin`, `date_fin` = '2023-01-10'
--------------
--------------
drop view if exists `vue_1`
--------------
--------------
create view `vue_1` as
select ref_fk,
max(`entree_qte`) as entree_qte,
max(`sortie_qte`) as sortie_qte
from ( select t1.`ref_fk`,
sum(t1.`qte`) as entree_qte,
0 as sortie_qte
from `entree` as t1
inner join `stock` as t2
on t2.`ref` = t1.`ref_fk`
where t1.`date` > t2.`date_deb`
and t1.`date` <= t2.`date_fin`
group by t1.`ref_fk`
union
select t1.`ref_fk`,
0 as entree_qte,
sum(t1.`qte`) as sortie_qte
from `sortie` as t1
inner join `stock` as t2
on t2.`ref` = t1.`ref_fk`
where t1.`date` > t2.`date_deb`
and t1.`date` <= t2.`date_fin`
group by t1.`ref_fk`
) as x
group by ref_fk
--------------
--------------
select * from `vue_1`
--------------
+--------+------------+------------+
| ref_fk | entree_qte | sortie_qte |
+--------+------------+------------+
| 1 | 35 | 5 |
| 2 | 60 | 10 |
| 3 | 60 | 20 |
| 4 | 50 | 0 |
| 5 | 80 | 0 |
+--------+------------+------------+
--------------
update `stock` as t1
inner join `vue_1` as t2
set t1.`initial` = t2.`entree_qte` - t2.`sortie_qte`
where t1.`ref` = t2.`ref_fk`
--------------
--------------
select * from `stock`
--------------
+-----+-------------+------+---------+------------+------------+
| ref | description | etat | initial | date_deb | date_fin |
+-----+-------------+------+---------+------------+------------+
| 1 | Stock A | 60 | 30 | 2022-12-31 | 2023-01-10 |
| 2 | Stock B | 60 | 50 | 2022-12-31 | 2023-01-10 |
| 3 | Stock C | 60 | 40 | 2022-12-31 | 2023-01-10 |
| 4 | Stock D | 55 | 50 | 2022-12-31 | 2023-01-10 |
| 5 | Stock E | 70 | 80 | 2022-12-31 | 2023-01-10 |
+-----+-------------+------+---------+------------+------------+
--------------
drop view if exists `vue_2`
--------------
--------------
create view `vue_2` as
select ref_fk,
max(`entree_qte`) as entree_qte,
max(`sortie_qte`) as sortie_qte
from ( select t1.`ref_fk`,
sum(t1.`qte`) as entree_qte,
0 as sortie_qte
from `entree` as t1
inner join `stock` as t2
on t2.`ref` = t1.`ref_fk`
where t1.`date` > t2.`date_fin`
group by t1.`ref_fk`
union
select t1.`ref_fk`,
0 as entree_qte,
sum(t1.`qte`) as sortie_qte
from `sortie` as t1
inner join `stock` as t2
on t2.`ref` = t1.`ref_fk`
where t1.`date` > t2.`date_fin`
group by t1.`ref_fk`
) as x
group by ref_fk
--------------
--------------
select * from `vue_2`
--------------
+--------+------------+------------+
| ref_fk | entree_qte | sortie_qte |
+--------+------------+------------+
| 1 | 30 | 0 |
| 2 | 10 | 0 |
| 3 | 20 | 0 |
| 4 | 15 | 10 |
| 5 | 30 | 40 |
+--------+------------+------------+
--------------
drop view if exists `vue_5`
--------------
--------------
create view `vue_3` as
select t1.`description`,
t1.`initial`,
t1.`date_deb`,
t1.`date_fin`,
t2.entree_qte,
t2.sortie_qte,
t1.`initial` + t2.entree_qte - t2.sortie_qte as reel_qte,
t1.`etat`,
t1.`initial` + t2.entree_qte - t2.sortie_qte - t1.`etat` as 'difference'
from `stock` as t1
inner join `vue_2` as t2
on t2.`ref_fk` = t1.`ref`
--------------
--------------
select * from `vue_3`
--------------
+-------------+---------+------------+------------+------------+------------+----------+------+------------+
| description | initial | date_deb | date_fin | entree_qte | sortie_qte | reel_qte | etat | difference |
+-------------+---------+------------+------------+------------+------------+----------+------+------------+
| Stock A | 30 | 2022-12-31 | 2023-01-10 | 30 | 0 | 60 | 60 | 0 |
| Stock B | 50 | 2022-12-31 | 2023-01-10 | 10 | 0 | 60 | 60 | 0 |
| Stock C | 40 | 2022-12-31 | 2023-01-10 | 20 | 0 | 60 | 60 | 0 |
| Stock D | 50 | 2022-12-31 | 2023-01-10 | 15 | 10 | 55 | 55 | 0 |
| Stock E | 80 | 2022-12-31 | 2023-01-10 | 30 | 40 | 70 | 70 | 0 |
+-------------+---------+------------+------------+------------+------------+----------+------+------------+
--------------
update `stock` as t1
inner join `vue_2` as t2
set t1.`initial` = t1.`initial` + t2.`entree_qte` - t2.`sortie_qte`, t1.`etat` = 0
where t1.`ref` = t2.`ref_fk`
--------------
--------------
select * from `stock`
--------------
+-----+-------------+------+---------+------------+------------+
| ref | description | etat | initial | date_deb | date_fin |
+-----+-------------+------+---------+------------+------------+
| 1 | Stock A | 0 | 60 | 2022-12-31 | 2023-01-10 |
| 2 | Stock B | 0 | 60 | 2022-12-31 | 2023-01-10 |
| 3 | Stock C | 0 | 60 | 2022-12-31 | 2023-01-10 |
| 4 | Stock D | 0 | 55 | 2022-12-31 | 2023-01-10 |
| 5 | Stock E | 0 | 70 | 2022-12-31 | 2023-01-10 |
+-----+-------------+------+---------+------------+------------+
--------------
COMMIT
--------------
Appuyez sur une touche pour continuer... |