Thread: referencing to "computed columns" in where clause
Is there a way to do things like select (a-b) as pippo from ... where pippo=7; or select case when (a>3) then a*b when (a<3) then a+b end as pippo where pippo<12; other than defining a function such that I can write: select func(a,b,c) as pippo from ... where func(a,b,c)=7; ? Is there anything else I can do to avoid duplication of code? -- Ivan Sergio Borgonovo http://www.webthatworks.it
On Tue, Jan 29, 2008 at 06:04:48PM +0100, Ivan Sergio Borgonovo wrote: > select > case > when (a>3) then a*b > when (a<3) then a+b > end as pippo > where pippo<12; I've tended to do: SELECT * FROM ( SELECT "complicated expression" AS pippo) x WHERE pippo < 12; Sam
On Tue, 29 Jan 2008 17:17:39 +0000 Sam Mason <sam@samason.me.uk> wrote: > On Tue, Jan 29, 2008 at 06:04:48PM +0100, Ivan Sergio Borgonovo > wrote: > > select > > case > > when (a>3) then a*b > > when (a<3) then a+b > > end as pippo > > where pippo<12; > > I've tended to do: > > SELECT * > FROM ( > SELECT "complicated expression" AS pippo) x > WHERE pippo < 12; It risk to be much harder to rewrite for dumber DB than repeating the "complicated expression". Does it come with some extra cost/improvement in term of performance compared to: - repeating the code of "complicated expression" - put it in a function with the proper "attributes" (I'd say IMMUTABLE in the above case) I've some argument for all cases but it should depend on the implementation. thanks -- Ivan Sergio Borgonovo http://www.webthatworks.it
--- On Tue, 1/29/08, Ivan Sergio Borgonovo <mail@webthatworks.it> wrote: >> other than defining a function such that I can write: SELECT ( a-b ) as pippo FROM Yourtable WHERE ( a-b ) = 7 UNION ALL SELECT ( a*b ) as pippo FROM Yourtable WHERE ( a*b ) < 12 AND a > 3 UNION ALL SELECT ( a+b ) as pippo FROM Yourtable WHERE ( a+b ) < 12 AND a < 3;
On Tue, Jan 29, 2008 at 06:49:50PM +0100, Ivan Sergio Borgonovo wrote: > On Tue, 29 Jan 2008 17:17:39 +0000 Sam Mason <sam@samason.me.uk> wrote: > > I've tended to do: > > > > SELECT * > > FROM ( > > SELECT "complicated expression" AS pippo) x > > WHERE pippo < 12; > > It risk to be much harder to rewrite for dumber DB than repeating the > "complicated expression". If you're worrying about how the various implementations handle the cases then I'd suggest testing the code in each one and see how they handle it. > Does it come with some extra cost/improvement in term of performance > compared to: > - repeating the code of "complicated expression" Most reasonable databases will expand subselects where possible. Optimisation is always a tradeoff between different factors--one of these being maintainability. > - put it in a function with the proper "attributes" (I'd say > IMMUTABLE in the above case) That's almost never going to be a win; rewriting sub-selects is almost always going to be easier than rewriting stored procedures. > I've some argument for all cases but it should depend on the > implementation. My recommendation is generally to use the easiest solution that works now and only worry about things when they actually fail. Sam