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
| mysql> use test Database changed mysql> show tables; Empty set (0.00 sec) mysql> create table person( id smallint unsigned NOT NULL AUTO_INCREMENT, name varchar(30), primary key(id)); Query OK, 0 rows affected (0.12 sec) mysql> create table score(id smallint unsigned NOT NULL, score int); Query OK, 0 rows affected (0.14 sec) mysql> show tables; + | Tables_in_test | + | person | | score | + 2 rows in set (0.00 sec) mysql> insert into person(name) values ('zrx'),('genius'),('stupid'); Query OK, 3 rows affected (0.11 sec) Records: 3 Duplicates: 0 Warnings: 0 mysql> select * from person; + | id | name | + | 1 | zrx | | 2 | genius | | 3 | stupid | + 3 rows in set (0.00 sec) mysql> insert into score values (1, 9),(2, 100); Query OK, 2 rows affected (0.11 sec) Records: 2 Duplicates: 0 Warnings: 0 mysql> insert into score values (4,20); Query OK, 1 row affected (0.11 sec)
mysql> insert into score values (1,1); Query OK, 1 row affected (0.11 sec) mysql> select * from score; + | id | score | + | 1 | 9 | | 2 | 100 | | 4 | 20 | | 1 | 1 | + 4 rows in set (0.00 sec)
mysql> select * from person inner join score ; + | id | name | id | score | + | 1 | zrx | 1 | 9 | | 2 | genius | 1 | 9 | | 3 | stupid | 1 | 9 | | 1 | zrx | 2 | 100 | | 2 | genius | 2 | 100 | | 3 | stupid | 2 | 100 | | 1 | zrx | 4 | 20 | | 2 | genius | 4 | 20 | | 3 | stupid | 4 | 20 | | 1 | zrx | 1 | 1 | | 2 | genius | 1 | 1 | | 3 | stupid | 1 | 1 | + 12 rows in set (0.00 sec)
mysql> select * from person inner join score where person.id=score.id; + | id | name | id | score | + | 1 | zrx | 1 | 9 | | 2 | genius | 2 | 100 | | 1 | zrx | 1 | 1 | + 3 rows in set (0.00 sec)
mysql> select * from (person, score); + | id | name | id | score | + | 1 | zrx | 1 | 9 | | 2 | genius | 1 | 9 | | 3 | stupid | 1 | 9 | | 1 | zrx | 2 | 100 | | 2 | genius | 2 | 100 | | 3 | stupid | 2 | 100 | | 1 | zrx | 4 | 20 | | 2 | genius | 4 | 20 | | 3 | stupid | 4 | 20 | | 1 | zrx | 1 | 1 | | 2 | genius | 1 | 1 | | 3 | stupid | 1 | 1 | + 12 rows in set (0.00 sec)
mysql> select * from (person, score) using (id); ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'using (id)' at line 1 mysql> select * from (person, score) where person.id=score.id; + | id | name | id | score | + | 1 | zrx | 1 | 9 | | 2 | genius | 2 | 100 | | 1 | zrx | 1 | 1 | + 3 rows in set (0.00 sec)
mysql> select * from person inner join score using (id); + | id | name | score | + | 1 | zrx | 9 | | 2 | genius | 100 | | 1 | zrx | 1 | + 3 rows in set (0.00 sec)
mysql> select * from person natural join score; + | id | name | score | + | 1 | zrx | 9 | | 2 | genius | 100 | | 1 | zrx | 1 | + 3 rows in set (0.00 sec)
mysql> select * from person left join score; ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near '' at line 1
mysql> select * from person left join score where person.id=score.id; ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'where person.id=score.id' at line 1
mysql> select * from person left join score using(id); + | id | name | score | + | 1 | zrx | 9 | | 1 | zrx | 1 | | 2 | genius | 100 | | 3 | stupid | NULL | + 4 rows in set (0.00 sec)
mysql> select * from person left join score on person.id=score.id; + | id | name | id | score | + | 1 | zrx | 1 | 9 | | 1 | zrx | 1 | 1 | | 2 | genius | 2 | 100 | | 3 | stupid | NULL | NULL | + 4 rows in set (0.00 sec)
mysql> select * from person right join score on person.id=score.id; + | id | name | id | score | + | 1 | zrx | 1 | 9 | | 2 | genius | 2 | 100 | | NULL | NULL | 4 | 20 | | 1 | zrx | 1 | 1 | + 4 rows in set (0.00 sec)
mysql> select * from person full outer join score on person.id=score.id; ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'outer join score on person.id=score.id' at line 1
mysql> select * from person full join score on person.id=score.id; ERROR 1054 (42S22): Unknown column 'person.id' in 'on clause' mysql> select * from person full join score using(id); + | id | name | score | + | 1 | zrx | 9 | | 2 | genius | 100 | | 1 | zrx | 1 | + 3 rows in set (0.00 sec)
mysql> select * from person full join score on person.id=score.id; ERROR 1054 (42S22): Unknown column 'person.id' in 'on clause'
mysql> select * from person p full join score s on p.id=s.id; ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'full join score s on p.id=s.id' at line 1
mysql> select * from person full outer join score using(id); ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'outer join score using(id)' at line 1
mysql> select * from person left join score using(id) union select * from person right join score using (id); + | id | name | score | + | 1 | zrx | 9 | | 1 | zrx | 1 | | 2 | genius | 100 | | 3 | stupid | NULL | | 1 | 9 | zrx | | 2 | 100 | genius | | 4 | 20 | NULL | | 1 | 1 | zrx | + 8 rows in set (0.00 sec)
mysql> select * from person left join score on person.id=score.id union select * from person right join score on person.id=score.id; + | id | name | id | score | + | 1 | zrx | 1 | 9 | | 1 | zrx | 1 | 1 | | 2 | genius | 2 | 100 | | 3 | stupid | NULL | NULL | | NULL | NULL | 4 | 20 | + 5 rows in set (0.00 sec)
|