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
|
--------------
SET AUTOCOMMIT = 0
--------------
--------------
START TRANSACTION
--------------
--------------
DROP DATABASE IF EXISTS `base`
--------------
--------------
CREATE DATABASE `base`
DEFAULT CHARACTER SET `latin1`
DEFAULT COLLATE `latin1_general_ci`
--------------
--------------
DROP TABLE IF EXISTS `mere`
--------------
--------------
CREATE TABLE `mere`
( `id` integer unsigned NOT NULL auto_increment primary key,
`val` varchar(255) NOT NULL
) ENGINE=InnoDB
DEFAULT CHARSET=`latin1` COLLATE=`latin1_general_ci`
ROW_FORMAT=COMPRESSED
--------------
--------------
insert into `mere` (`val`) values
('un'),('deux'),('un'),('deux')
--------------
--------------
select * from mere
--------------
+----+------+
| id | val |
+----+------+
| 1 | un |
| 2 | deux |
| 3 | un |
| 4 | deux |
+----+------+
--------------
DROP TABLE IF EXISTS `fille`
--------------
--------------
CREATE TABLE IF NOT EXISTS `fille`
( `id` INTEGER UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
`mere_id` INTEGER UNSIGNED NOT NULL,
`lib` VARCHAR(255) NOT NULL,
CONSTRAINT `FK_FILLE_MERE` FOREIGN KEY (`mere_id`) REFERENCES `mere` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB
DEFAULT CHARSET=latin1 COLLATE=latin1_general_ci
ROW_FORMAT=COMPRESSED
--------------
--------------
insert into `fille` (`mere_id`,`lib`) values
(1,'one'),(1,'two'),(1,'one'),(1,'two'),
(3,'two'),(3,'one'),(3,'two'),(3,'one'),
(2,'one'),(2,'two'),(2,'one'),(2,'two'),
(4,'two'),(4,'one'),(4,'two'),(4,'one')
--------------
--------------
select * from fille
--------------
+----+---------+-----+
| id | mere_id | lib |
+----+---------+-----+
| 1 | 1 | one |
| 2 | 1 | two |
| 3 | 1 | one |
| 4 | 1 | two |
| 5 | 3 | two |
| 6 | 3 | one |
| 7 | 3 | two |
| 8 | 3 | one |
| 9 | 2 | one |
| 10 | 2 | two |
| 11 | 2 | one |
| 12 | 2 | two |
| 13 | 4 | two |
| 14 | 4 | one |
| 15 | 4 | two |
| 16 | 4 | one |
+----+---------+-----+
--------------
select m.id, group_concat(m.val, '-', f.lib order by m.val, f.lib separator ',') as group_concat
from mere as m
inner join fille as f
on f.mere_id = m.id
group by m.id
--------------
+----+-------------------------------------+
| id | group_concat |
+----+-------------------------------------+
| 1 | un-one,un-one,un-two,un-two |
| 2 | deux-one,deux-one,deux-two,deux-two |
| 3 | un-one,un-one,un-two,un-two |
| 4 | deux-one,deux-one,deux-two,deux-two |
+----+-------------------------------------+
--------------
select m.id, group_concat(distinct m.val, '-', f.lib order by m.val, f.lib separator ',') as group_concat
from mere as m
inner join fille as f
on f.mere_id = m.id
group by m.id
--------------
+----+-------------------+
| id | group_concat |
+----+-------------------+
| 1 | un-one,un-two |
| 2 | deux-one,deux-two |
| 3 | un-one,un-two |
| 4 | deux-one,deux-two |
+----+-------------------+
--------------
COMMIT
--------------
--------------
SET AUTOCOMMIT = 1
--------------
Appuyez sur une touche pour continuer... |
Partager