June 8, 2012 at 6:08 am
select * from test a inner join test1 b
on a.id=b.module_id
where a.id=@id
and a.name=@name
if (@age >12)
AND CONVERT(CHAR(8), a.start_dt, 112) <= dbo.fCM_Get_UTC_Date_Str(GetDate(), GetUTCDate())
if (@age <12)
AND CONVERT(CHAR(8), a.start_dt, 112) <= dbo.fCM_Get_UTC_Date_Str_Latest(GetDate(), GetUTCDate())
here it's giving me an error "multi part identifier a.start_dt couldn't be found"
help ???
June 8, 2012 at 6:12 am
One option is dynamic sql, much like the below
declare @sql nvarchar(max), @age int, @id int
set @sql = '
select
*
from
test a
inner join
test1 b
on
a.id=b.module_id
where
a.id=@id
and
a.name=@name'
if (@age >12)
set @sql = @sql + ' AND CONVERT(CHAR(8), a.start_dt, 112) <= dbo.fCM_Get_UTC_Date_Str(GetDate(), GetUTCDate())'
if (@age <12)
set @sql = @sql + ' AND CONVERT(CHAR(8), a.start_dt, 112) <= dbo.fCM_Get_UTC_Date_Str_Latest(GetDate(), GetUTCDate())'
select @sql
sp_executesql (@sql)
Edit - change the begining, as there are other solutions
June 8, 2012 at 6:21 am
You Can try the below query.........
select * from test a inner join test1 b
on a.id=b.module_id
where a.id=@id
and a.name=@name
and (CONVERT(CHAR(8), a.start_dt, 112) <= case when @age>12 then dbo.fCM_Get_UTC_Date_Str(GetDate(), GetUTCDate())
when @age<12 then dbo.fCM_Get_UTC_Date_Str_Latest(GetDate(), GetUTCDate()) end)
June 8, 2012 at 6:27 am
anthony.green (6/8/2012)
Needs to become dynamic sql...
Doesn't need to, but possibly better performance than the alternative:
select * from test a
inner join test1 b
on a.id=b.module_id
where a.id=@id
and a.name=@name
AND CONVERT(CHAR(8), a.start_dt, 112) <= CASE
WHEN @age >12 THEN dbo.fCM_Get_UTC_Date_Str(GetDate(), GetUTCDate())
ELSE dbo.fCM_Get_UTC_Date_Str_Latest(GetDate(), GetUTCDate()) END
Either way, the op should Google "SARGability" to see what CONVERT(CHAR(8), a.start_dt, 112) is going to do to performance.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
June 8, 2012 at 6:34 am
Thanks !!!
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply