question

bvolk avatar image
bvolk asked

Converting error in having clause

Hello, I'm receiving a conversion error in my having clause. "Conversion failed when converting the varchar value '[2010-08-01]' to data type int" I have columns named [2010-08-01] respectively for each month... I'm trying to create a having clause that will only return rows greater than zero in the most current month. This works... having [2010-08-01] > 0 but when I write it like this (below), to make sure I always get the current month, I get a conversion error: having '['+ replace(convert(char(8),getdate(),111),'/','-') + '01]' > 0 I think...(from reseaching the problem) that SQL is converting the char to int when it sees '+'. I've tried converting the entire string but that didn't work either. Any ideas how I can write this where I won't get the error? Thanks in advance for any help!! Brian
t-sqlcast-convert
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Matt Whitfield avatar image
Matt Whitfield answered
You need to use dynamic SQL for this. When you say `[2010-08-01] > 0` you are saying 'compare the value in the column named 2010-08-01 to 0'. When you say `'['+ replace(convert(char(8),getdate(),111),'/','-') + '01]' > 0` you are saying 'compare the string value '[2010-08-01]' to 0'. To get this to work as you want, you need to use dynamic SQL whereby you build up the string and then execute it using `sp_executesql` or `EXEC`. Alternatively, you can use `UNPIVOT` to get the tabular results into a more natural table result, and query it using normal SQL.
3 comments
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

bvolk avatar image bvolk commented ·
thanks for help! I tried dynamic SQL and I still get the same error. this is what I did: ALTER procedure [dbo].[sp_InvCubeWeightByDate] @Whse varchar(10), @Date varchar(12) -- select, from, group having @Date > 0 and ran it like this: exec sp_InvCubeWeightByDate 'chi', [2010-08-01] I still get he same error... I'm guessing I'm still doing something wrong?
0 Likes 0 ·
Matt Whitfield avatar image Matt Whitfield ♦♦ commented ·
What you have done there is exactly the same - you have declared a string variable, and asked SQL Server to compare a string to an int. You need something more like - DECLARE @sql varchar(MAX) SET @Sql = 'SELECT ... HAVING ' + @Date + ' > 0' EXEC (@sql)
0 Likes 0 ·
bvolk avatar image bvolk commented ·
thank you! I did figure it out ... you were correct, I just needed to get my head around it. ..it's not pretty, but it works! :-) I'll post my work. Thanks again for you help!
0 Likes 0 ·
bvolk avatar image
bvolk answered
below is my solution... declare @tmpColumn varchar(12); set @tmpColumn = replace(convert(char(8),getdate(),111),'/','-') + '01' exec (' declare @Whse varchar(10) set @Whse = ''chi'' select i.itemclassdesc , i.itemsubclassdesc , #i.itemnum , #i.strat , i.itemdesc, #i.uom , sceweight , scewidth , secdepth , sceheight , cube , onhandweight , onhandcube , isnull([2009-11-01],0) as [2009-11-01] , isnull([2009-12-01],0) as [2009-12-01] , isnull([2010-01-01],0) as [2010-01-01] , isnull([2010-02-01],0) as [2010-02-01] , isnull([2010-03-01],0) as [2010-03-01] , isnull([2010-04-01],0) as [2010-04-01] , isnull([2010-05-01],0) as [2010-05-01] , isnull([2010-06-01],0) as [2010-06-01] , isnull([2010-07-01],0) as [2010-07-01] , isnull([2010-08-01],0) as [2010-08-01] , isnull([2010-09-01],0) as [2010-09-01] , isnull([2010-10-01],0) as [2010-10-01] , isnull([2010-11-01],0) as [2010-11-01] , isnull([2010-12-01],0) as [2010-12-01] from #i left outer join ditem i on #i.itemnum = i.itemnum inner join ax_mbsfcreordertable r on i.itemnum = r.itemid and r.inventlocationid = @Whse and r.active = 1 where i.itemnum not like ''@%'' group by i.itemclassdesc , i.itemsubclassdesc , #i.itemnum , #i.strat , i.itemdesc , #i.uom , sceweight , scewidth , secdepth , sceheight , cube , onhandweight , onhandcube , [2009-11-01] , [2009-12-01] , [2010-01-01] , [2010-02-01] , [2010-03-01] , [2010-04-01] , [2010-05-01] , [2010-06-01] , [2010-07-01] , [2010-08-01] , [2010-09-01] , [2010-10-01] , [2010-11-01] , [2010-12-01] having ['+ @tmpColumn +'] > 0 order by 1,2')
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Write an Answer

Hint: Notify or tag a user in this post by typing @username.

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.