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
| --------------
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 `client`
--------------
--------------
CREATE TABLE `client`
( `id` integer unsigned NOT NULL auto_increment primary key,
`nom` varchar(255) NOT NULL
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_ci`
ROW_FORMAT=COMPRESSED
--------------
--------------
INSERT INTO `client` (`nom`) values
('Nom Un'),('Nom Deux'),('Nom Trois'),('Nom Quatre'),('Nom Cinq'),('Nom Six')
--------------
--------------
select * from `client`
--------------
+----+------------+
| id | nom |
+----+------------+
| 1 | Nom Un |
| 2 | Nom Deux |
| 3 | Nom Trois |
| 4 | Nom Quatre |
| 5 | Nom Cinq |
| 6 | Nom Six |
+----+------------+
--------------
DROP TABLE IF EXISTS `facture`
--------------
--------------
CREATE TABLE `facture`
( `id` integer unsigned NOT NULL auto_increment primary key,
`client_id` integer unsigned NOT NULL,
`montant` decimal(15,2) NOT NULL,
`date` date NOT NULL
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_ci`
ROW_FORMAT=COMPRESSED
--------------
--------------
INSERT INTO `facture` (`client_id`,`montant`,`date`) values
(1, 125.00,'2023-01-05'),(2, 432.00,'2023-01-07'),(3,100.0,'2023-01-02'),(4,251.00,'2023-01-07'),(5,200.00,'2023-01-08')
--------------
--------------
select * from `facture`
--------------
+----+-----------+---------+------------+
| id | client_id | montant | date |
+----+-----------+---------+------------+
| 1 | 1 | 125.00 | 2023-01-05 |
| 2 | 2 | 432.00 | 2023-01-07 |
| 3 | 3 | 100.00 | 2023-01-02 |
| 4 | 4 | 251.00 | 2023-01-07 |
| 5 | 5 | 200.00 | 2023-01-08 |
+----+-----------+---------+------------+
--------------
DROP TABLE IF EXISTS `paiement`
--------------
--------------
CREATE TABLE `paiement`
( `id` integer unsigned NOT NULL auto_increment primary key,
`client_id` integer unsigned NOT NULL,
`montant` decimal(15,2) NOT NULL,
`date` date NOT NULL
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_ci`
ROW_FORMAT=COMPRESSED
--------------
--------------
INSERT INTO `paiement` (`client_id`,`montant`,`date`) values
(3,252.0,'2023-01-06'),(4,125.0,'2023-01-09'),(4,126.0,'2023-01-12'),(5,150.0,'2023-01-11')
--------------
--------------
select * from `paiement`
--------------
+----+-----------+---------+------------+
| id | client_id | montant | date |
+----+-----------+---------+------------+
| 1 | 3 | 252.00 | 2023-01-06 |
| 2 | 4 | 125.00 | 2023-01-09 |
| 3 | 4 | 126.00 | 2023-01-12 |
| 4 | 5 | 150.00 | 2023-01-11 |
+----+-----------+---------+------------+
--------------
drop view if exists `vue_1`
--------------
--------------
create view `vue_1` as
select t2.nom,
sum(t1.facture) as facture,
sum(t1.paiement) as paiement,
sum(t1.paiement - t1.facture) as difference
from ( select client_id as client,
`date`,
montant as facture,
0 as paiement
from facture
union
select client_id as client,
`date`,
0 as facture,
montant as paiement
from paiement
) as t1
inner join client as t2
on t2.id = t1.client
where t1.`date` < '2023-01-15'
group by client
order by client
--------------
--------------
select * from `vue_1` where difference > 0
--------------
+-----------+---------+----------+------------+
| nom | facture | paiement | difference |
+-----------+---------+----------+------------+
| Nom Trois | 100.00 | 252.00 | 152.00 |
+-----------+---------+----------+------------+
--------------
select * from `vue_1` where difference = 0
--------------
+------------+---------+----------+------------+
| nom | facture | paiement | difference |
+------------+---------+----------+------------+
| Nom Quatre | 251.00 | 251.00 | 0.00 |
+------------+---------+----------+------------+
--------------
select * from `vue_1` where difference < 0
--------------
+----------+---------+----------+------------+
| nom | facture | paiement | difference |
+----------+---------+----------+------------+
| Nom Un | 125.00 | 0.00 | -125.00 |
| Nom Deux | 432.00 | 0.00 | -432.00 |
| Nom Cinq | 200.00 | 150.00 | -50.00 |
+----------+---------+----------+------------+
--------------
drop view if exists `vue_2`
--------------
--------------
create view `vue_2` as
select t1.nom,
coalesce(t2.facture, 0) as facture,
coalesce(t3.paiement, 0) as paiement,
coalesce(paiement,0) - coalesce(facture,0) as difference
from `client` as t1
left outer join ( select client_id,
sum(montant) as facture
from `facture`
where `date` < '2023-01-15'
group by client_id
) as t2
on t2.client_id = t1.id
left outer join ( select client_id,
sum(montant) as paiement
from `paiement`
where `date` < '2023-01-15'
group by client_id
) as t3
on t3.client_id = t1.id
where t2.facture is not null
or t3.paiement is not null
order by t1.id
--------------
--------------
select * from `vue_2` where difference > 0
--------------
+-----------+---------+----------+------------+
| nom | facture | paiement | difference |
+-----------+---------+----------+------------+
| Nom Trois | 100.00 | 252.00 | 152.00 |
+-----------+---------+----------+------------+
--------------
select * from `vue_2` where difference = 0
--------------
+------------+---------+----------+------------+
| nom | facture | paiement | difference |
+------------+---------+----------+------------+
| Nom Quatre | 251.00 | 251.00 | 0.00 |
+------------+---------+----------+------------+
--------------
select * from `vue_2` where difference < 0
--------------
+----------+---------+----------+------------+
| nom | facture | paiement | difference |
+----------+---------+----------+------------+
| Nom Un | 125.00 | 0.00 | -125.00 |
| Nom Deux | 432.00 | 0.00 | -432.00 |
| Nom Cinq | 200.00 | 150.00 | -50.00 |
+----------+---------+----------+------------+
--------------
COMMIT
--------------
Appuyez sur une touche pour continuer... |
Partager