Bug #33254 Invalid query: Unknown column 'column_id' in 'on clause'
Submitted: 14 Dec 2007 22:56 Modified: 16 Dec 2007 19:01
Reporter: Aleksandr Zakharov Email Updates:
Status: Not a Bug Impact on me:
None 
Category:MySQL Server: DML Severity:S1 (Critical)
Version:mysql 5.0.27 OS:FreeBSD (6.2)
Assigned to: CPU Architecture:Any
Tags: clause, column, UNKNOWN

[14 Dec 2007 22:56] Aleksandr Zakharov
Description:
MySQL 5.0.27 up to date
Storage engine: MylSAM

Query:

SELECT m.model_id, mv.visit, st.type
FROM model m, service_type st
LEFT JOIN model_visit mv ON m.model_id = mv.model_id
WHERE m.acc_id = '1'
AND st.service_type_id = m.type_id
GROUP BY m.model_id

mysql responce:
#1054 - Unknown column 'm.model_id' in 'on clause'

I believe this bug similar to closed bug # 13551

How to repeat:
This problem occures when query contains JOIN clause and FROM clause contains more than one table.

For example the following query works properly:

SELECT m.model_id, mv.visit
FROM model m
LEFT JOIN model_visit mv ON m.model_id = mv.model_id
WHERE m.acc_id = '1'
GROUP BY m.model_id
[15 Dec 2007 8:23] Valeriy Kravchuk
This is not a bug. Please, read the manual, http://dev.mysql.com/doc/refman/5.0/en/join.html:

"- Previously, the comma operator (,) and JOIN both had the same precedence, so the join expression t1, t2 JOIN t3 was interpreted as ((t1, t2) JOIN t3). Now JOIN has higher precedence, so the expression is interpreted as (t1, (t2 JOIN t3)). This change affects statements that use an ON clause, because that clause can refer only to columns in the operands of the join, and the change in precedence changes interpretation of what those operands are.

Example:

CREATE TABLE t1 (i1 INT, j1 INT);
CREATE TABLE t2 (i2 INT, j2 INT);
CREATE TABLE t3 (i3 INT, j3 INT);
INSERT INTO t1 VALUES(1,1);
INSERT INTO t2 VALUES(1,1);
INSERT INTO t3 VALUES(1,1);
SELECT * FROM t1, t2 JOIN t3 ON (t1.i1 = t3.i3);

Previously, the SELECT was legal due to the implicit grouping of t1,t2 as (t1,t2). Now the JOIN takes precedence, so the operands for the ON clause are t2 and t3. Because t1.i1 is not a column in either of the operands, the result is an Unknown column 't1.i1' in 'on clause' error. To allow the join to be processed, group the first two tables explicitly with parentheses so that the operands for the ON clause are (t1,t2) and t3:

SELECT * FROM (t1, t2) JOIN t3 ON (t1.i1 = t3.i3);

Alternatively, avoid the use of the comma operator and use JOIN instead:

SELECT * FROM t1 JOIN t2 JOIN t3 ON (t1.i1 = t3.i3);

This change also applies to statements that mix the comma operator with INNER JOIN, CROSS JOIN, LEFT JOIN, and RIGHT JOIN, all of which now have higher precedence than the comma operator."
[16 Dec 2007 19:01] Aleksandr Zakharov
Thank you Valeriy for an explanation.
Everything works