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
| --------------
START TRANSACTION
--------------
--------------
set session collation_connection = "latin1_general_ci"
--------------
--------------
DROP DATABASE IF EXISTS `base`
--------------
--------------
CREATE DATABASE IF NOT EXISTS `base`
DEFAULT CHARACTER SET `latin1`
DEFAULT COLLATE `latin1_general_cs`
--------------
--------------
DROP TABLE IF EXISTS `Trav`
--------------
--------------
CREATE TABLE `Trav`
( `codart` integer unsigned NOT NULL Primary Key,
`reference` varchar(255) NOT NULL,
`designation` varchar(255) NOT NULL,
`exercice` integer unsigned NOT NULL,
`stock` decimal(15,0) NOT NULL,
`partenaire` decimal(15,0) NOT NULL
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_cs`
ROW_FORMAT=COMPRESSED
--------------
--------------
DROP TABLE IF EXISTS `ast_article`
--------------
--------------
CREATE TABLE `ast_article`
( `id` integer unsigned NOT NULL AUTO_INCREMENT Primary Key,
`reference` varchar(255) NOT NULL,
`designation` varchar(255) NOT NULL
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_cs`
ROW_FORMAT=COMPRESSED
--------------
--------------
insert into `ast_article` (`id`,`reference`,`designation`) values
(25, 'article 25', 'cuillère'),
(37, 'article 37', 'fourchette'),
(42, 'article 42', 'couteau'),
(53, 'article 53', 'assiette')
--------------
--------------
select * from `ast_article`
--------------
+----+------------+-------------+
| id | reference | designation |
+----+------------+-------------+
| 25 | article 25 | cuillère |
| 37 | article 37 | fourchette |
| 42 | article 42 | couteau |
| 53 | article 53 | assiette |
+----+------------+-------------+
--------------
DROP TABLE IF EXISTS `ligne_tstock`
--------------
--------------
CREATE TABLE `ligne_tstock`
( `id` integer unsigned NOT NULL AUTO_INCREMENT Primary Key,
`code_article` integer unsigned NOT NULL,
`exercice` integer unsigned NOT NULL,
`mouvement` varchar(255) NOT NULL,
`qte_transfert` decimal(15,0) NOT NULL,
unique index `idx` (`code_article`,`exercice`,`mouvement`)
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_cs`
ROW_FORMAT=COMPRESSED
--------------
--------------
insert into `ligne_tstock` (`code_article`,`exercice`,`mouvement`,`qte_transfert`) values
(25,2020,'entree',25),(25,2020,'sortie',17),
(25,2021,'entree',74),(25,2021,'sortie',12),
(25,2022,'entree',34),(25,2022,'sortie',45),
(37,2020,'entree',55),(37,2020,'sortie',47),
(37,2021,'entree',68),(37,2021,'sortie',05),
(37,2022,'entree',21),(37,2022,'sortie',17),
(42,2020,'entree',74),(42,2020,'sortie',44),
(42,2021,'entree',47),(42,2021,'sortie',25),
(42,2022,'entree',26),(42,2022,'sortie',07),
(53,2020,'entree',98),(53,2020,'sortie',55),
(53,2021,'entree',44),(53,2021,'sortie',22),
(53,2022,'entree',02),(53,2022,'sortie',12)
--------------
--------------
select * from `ligne_tstock`
--------------
+----+--------------+----------+-----------+---------------+
| id | code_article | exercice | mouvement | qte_transfert |
+----+--------------+----------+-----------+---------------+
| 1 | 25 | 2020 | entree | 25 |
| 2 | 25 | 2020 | sortie | 17 |
| 3 | 25 | 2021 | entree | 74 |
| 4 | 25 | 2021 | sortie | 12 |
| 5 | 25 | 2022 | entree | 34 |
| 6 | 25 | 2022 | sortie | 45 |
| 7 | 37 | 2020 | entree | 55 |
| 8 | 37 | 2020 | sortie | 47 |
| 9 | 37 | 2021 | entree | 68 |
| 10 | 37 | 2021 | sortie | 5 |
| 11 | 37 | 2022 | entree | 21 |
| 12 | 37 | 2022 | sortie | 17 |
| 13 | 42 | 2020 | entree | 74 |
| 14 | 42 | 2020 | sortie | 44 |
| 15 | 42 | 2021 | entree | 47 |
| 16 | 42 | 2021 | sortie | 25 |
| 17 | 42 | 2022 | entree | 26 |
| 18 | 42 | 2022 | sortie | 7 |
| 19 | 53 | 2020 | entree | 98 |
| 20 | 53 | 2020 | sortie | 55 |
| 21 | 53 | 2021 | entree | 44 |
| 22 | 53 | 2021 | sortie | 22 |
| 23 | 53 | 2022 | entree | 2 |
| 24 | 53 | 2022 | sortie | 12 |
+----+--------------+----------+-----------+---------------+
--------------
DROP TABLE IF EXISTS `ligne_tpartenaire`
--------------
--------------
CREATE TABLE `ligne_tpartenaire`
( `id` integer unsigned NOT NULL AUTO_INCREMENT Primary Key,
`code_article` integer unsigned NOT NULL,
`exercice` integer unsigned NOT NULL,
`mouvement` varchar(255) NOT NULL,
`qte_transfert` decimal(15,0) NOT NULL,
unique index `idx` (`code_article`,`exercice`,`mouvement`)
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_cs`
ROW_FORMAT=COMPRESSED
--------------
--------------
insert into `ligne_tpartenaire` (`code_article`,`exercice`,`mouvement`,`qte_transfert`) values
(25,2020,'entree',55),(25,2020,'sortie',47),
(25,2021,'entree',68),(25,2021,'sortie',05),
(25,2022,'entree',21),(25,2022,'sortie',17),
(37,2020,'entree',74),(37,2020,'sortie',44),
(37,2021,'entree',47),(37,2021,'sortie',25),
(37,2022,'entree',26),(37,2022,'sortie',07),
(42,2020,'entree',98),(42,2020,'sortie',55),
(42,2021,'entree',44),(42,2021,'sortie',22),
(42,2022,'entree',02),(42,2022,'sortie',12),
(53,2020,'entree',25),(53,2020,'sortie',17),
(53,2021,'entree',74),(53,2021,'sortie',12),
(53,2022,'entree',34),(53,2022,'sortie',45)
--------------
--------------
select * from `ligne_tpartenaire`
--------------
+----+--------------+----------+-----------+---------------+
| id | code_article | exercice | mouvement | qte_transfert |
+----+--------------+----------+-----------+---------------+
| 1 | 25 | 2020 | entree | 55 |
| 2 | 25 | 2020 | sortie | 47 |
| 3 | 25 | 2021 | entree | 68 |
| 4 | 25 | 2021 | sortie | 5 |
| 5 | 25 | 2022 | entree | 21 |
| 6 | 25 | 2022 | sortie | 17 |
| 7 | 37 | 2020 | entree | 74 |
| 8 | 37 | 2020 | sortie | 44 |
| 9 | 37 | 2021 | entree | 47 |
| 10 | 37 | 2021 | sortie | 25 |
| 11 | 37 | 2022 | entree | 26 |
| 12 | 37 | 2022 | sortie | 7 |
| 13 | 42 | 2020 | entree | 98 |
| 14 | 42 | 2020 | sortie | 55 |
| 15 | 42 | 2021 | entree | 44 |
| 16 | 42 | 2021 | sortie | 22 |
| 17 | 42 | 2022 | entree | 2 |
| 18 | 42 | 2022 | sortie | 12 |
| 19 | 53 | 2020 | entree | 25 |
| 20 | 53 | 2020 | sortie | 17 |
| 21 | 53 | 2021 | entree | 74 |
| 22 | 53 | 2021 | sortie | 12 |
| 23 | 53 | 2022 | entree | 34 |
| 24 | 53 | 2022 | sortie | 45 |
+----+--------------+----------+-----------+---------------+
--------------
DROP PROCEDURE IF EXISTS `inventaire`
--------------
--------------
CREATE PROCEDURE `inventaire` ( In _exercice integer unsigned,
Out _cumul integer unsigned)
DETERMINISTIC
NO SQL
BEGIN
DECLARE _codart INTEGER UNSIGNED DEFAULT 0;
DECLARE _refere VARCHAR(255) DEFAULT NULL;
DECLARE _design VARCHAR(255) DEFAULT NULL;
DECLARE _stock DECIMAL(15,0) DEFAULT 0;
DECLARE _part DECIMAL(15,0) DEFAULT 0;
DECLARE _fin INTEGER UNSIGNED DEFAULT 1;
DECLARE _tab CURSOR FOR SELECT id, reference, designation FROM `ast_article`;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET _fin = 0;
SET _cumul = 0;
OPEN _tab;
FETCH _tab INTO _codart, _refere, _design;
WHILE (_fin)
DO
SELECT sum(case when mouvement = 'entree' then +coalesce(qte_transfert,0)
when mouvement = 'sortie' then -coalesce(qte_transfert,0)
else 0 end)
INTO _stock
FROM ligne_tstock
WHERE code_article = _codart
AND exercice = _exercice;
SELECT sum(case when mouvement = 'entree' then +coalesce(qte_transfert,0)
when mouvement = 'sortie' then -coalesce(qte_transfert,0)
else 0 end)
INTO _part
FROM ligne_tpartenaire
WHERE code_article = _codart
AND exercice = _exercice;
INSERT INTO `trav` (`codart`,`reference`,`designation`,`exercice`,`stock`,`partenaire`) values (_codart,_refere,_design,_exercice,_stock,_part);
SET _cumul = _cumul + _stock + _part;
FETCH _tab INTO _codart, _refere, _design;
END WHILE;
CLOSE _tab;
END
--------------
--------------
set @total = 0
--------------
--------------
call `inventaire` (2020, @total)
--------------
--------------
select @total as Total_Général
--------------
+---------------+
| Total_Général |
+---------------+
| 178 |
+---------------+
--------------
select * from trav
--------------
+--------+------------+-------------+----------+-------+------------+
| codart | reference | designation | exercice | stock | partenaire |
+--------+------------+-------------+----------+-------+------------+
| 25 | article 25 | cuillère | 2020 | 8 | 8 |
| 37 | article 37 | fourchette | 2020 | 8 | 30 |
| 42 | article 42 | couteau | 2020 | 30 | 43 |
| 53 | article 53 | assiette | 2020 | 43 | 8 |
+--------+------------+-------------+----------+-------+------------+
--------------
COMMIT
--------------
Appuyez sur une touche pour continuer... |
Partager