Thread: bug in 9.2.2 ? subquery accepts wrong column name : upd
dynacom=# SELECT DISTINCT ON (qry.setid) qry.setid, qry.arragg[1:2] FROM (select distinct sst.setid,(array_agg(vsl.name)OVER (PARTITION BY sst.setid ORDER BY character_length(vsl.name))) as arragg FROM sissets sst,vessels vsl WHERE vsl.id=sst.vslid ORDER BY sst.setid) as qry WHERE array_length(qry.arragg,1)>1 AND qry.setid IN(SELECT setid from sis_oper_cons) ORDER BY qry.setid,array_length(qry.arragg,1);setid | arragg -------+---------------------------------- 54 | {EQUZZZ,SAMZZZ} 55 | {"ZZZR","ZZZTRAVEL"} 81 | {"ZZZ SISTER","ZZZ DUMMYII"} (3 rows) however, there is not column setid in sis_oper_cons, dynacom=# SELECT setid from sis_oper_cons; ERROR: column "setid" does not exist LINE 1: SELECT setid from sis_oper_cons; ^ 9.2.2 Postgresql treats qry.setid IN (SELECT setid from sis_oper_cons) as true. However, making subquery look like (SELECT soc.setid from sis_oper_cons soc), as in dynacom=# SELECT DISTINCT ON (qry.setid) qry.setid, qry.arragg[1:2] FROM (select distinct sst.setid,(array_agg(vsl.name)OVER (PARTITION BY sst.setid ORDER BY character_length(vsl.name))) as arragg FROM sissets sst,vessels vsl WHERE vsl.id=sst.vslid ORDER BY sst.setid) as qry WHERE array_length(qry.arragg,1)>1 AND qry.setid NOT IN(SELECT soc.setid from sis_oper_cons soc) ORDER BY qry.setid,array_length(qry.arragg,1); ERROR: column soc.setid does not exist LINE 1: ...gth(qry.arragg,1)>1 AND qry.setid NOT IN (SELECT soc.setid ... ^ dynacom=# postgresql corerctly identifies and throws the error. - Achilleas Mantzios IT DEV IT DEPT Dynacom Tankers Mgmt
Achilleas Mantzios <achill@matrix.gatewaynet.com> writes: > dynacom=# SELECT DISTINCT ON (qry.setid) qry.setid, qry.arragg[1:2] FROM > (select distinct sst.setid,(array_agg(vsl.name) OVER (PARTITION BY sst.setid ORDER BY character_length(vsl.name)))as arragg > FROM sissets sst, vessels vsl WHERE vsl.id=sst.vslid ORDER BY sst.setid) as qry > WHERE array_length(qry.arragg,1)>1 AND qry.setid IN (SELECT setid from sis_oper_cons) ORDER BY qry.setid,array_length(qry.arragg,1); > [ works ] > however, there is not column setid in sis_oper_cons, If not, that's a perfectly legal outer reference to qry.setid. Probably not one of SQL's better design features, since it confuses people regularly; but it's required by spec to work like that. regards, tom lane
Thanx Tom. On Πεμ 14 ÎÎ±Ï 2013 12:17:46 Tom Lane wrote: > Achilleas Mantzios <achill@matrix.gatewaynet.com> writes: > > dynacom=# SELECT DISTINCT ON (qry.setid) qry.setid, qry.arragg[1:2] FROM > > (select distinct sst.setid,(array_agg(vsl.name) OVER (PARTITION BY sst.setid ORDER BY character_length(vsl.name)))as arragg > > FROM sissets sst, vessels vsl WHERE vsl.id=sst.vslid ORDER BY sst.setid) as qry > > WHERE array_length(qry.arragg,1)>1 AND qry.setid IN (SELECT setid from sis_oper_cons) ORDER BY qry.setid,array_length(qry.arragg,1); > > [ works ] > > > however, there is not column setid in sis_oper_cons, > > If not, that's a perfectly legal outer reference to qry.setid. > > Probably not one of SQL's better design features, since it confuses > people regularly; but it's required by spec to work like that. > > regards, tom lane > > > - Achilleas Mantzios IT DEV IT DEPT Dynacom Tankers Mgmt