Syntax error in Dynamic SQL - SQL Server 2000

  • Hi all,

    I am having problems debugging the following scrip containing dynamic SQL. Can anyone tell me what causes this error?

    use webproxy

    DECLARE @tempsql varchar(2000)

    select @tempsql =

    ''declare @xmonth varchar(2)

    declare @xyear varchar(4)

    declare @xdate varchar(10)

    declare @rptmonth datetime

    select @xmonth = MONTH(dateadd(month,-1,getdate()))

    select @xyear = YEAR(dateadd(month,-1,getdate()))

    select @xdate = @xmonth + '/01/' + @xyear

    select @rptmonth = cast(@xdate as datetime)

    set rowcount 0

    select dbo.user_parser(clientusername) as "_user",

    count(*) as "objects",

    sum(cast(bytessent as float))as "bytes_sent",

    sum(cast(bytesrecvd as float))as "bytes_received",

    (sum(cast(bytessent as float)) + sum(cast(bytesrecvd as float)))as "total_bytes",

    @rptmonth as "rpt_month"

    ----into ##top100temp

    from webproxylog'' + ''''+cast(month(dateadd(m,-2,getdate())) as varchar(2)) + ''''

    --from webproxylog5

    where dbo.user_parser(clientusername) <> " "

    group by dbo.user_parser(clientusername)

    order by total_bytes desc''

    --print @tempsql

    execute (@tempsql)

    The above script results in the following error message:

    Msg 170, Level 15, State 1, Line 21

    Line 21: Incorrect syntax near ''.

    Appreciate your assistance,

    Seyed

  • You have some problems with your quotes. I'm not sure that I did the right corrections. Use the print to run the query that gets printed and debug from it.

    use webproxy

    DECLARE @tempsql varchar(2000)

    select @tempsql =

    'declare @xmonth varchar(2)

    declare @xyear varchar(4)

    declare @xdate varchar(10)

    declare @rptmonth datetime

    select @xmonth = MONTH(dateadd(month,-1,getdate()))

    select @xyear = YEAR(dateadd(month,-1,getdate()))

    select @xdate = @xmonth + ''/01/'' + @xyear

    select @rptmonth = cast(@xdate as datetime)

    set rowcount 0

    select dbo.user_parser(clientusername) as "_user",

    count(*) as "objects",

    sum(cast(bytessent as float))as "bytes_sent",

    sum(cast(bytesrecvd as float))as "bytes_received",

    (sum(cast(bytessent as float)) + sum(cast(bytesrecvd as float)))as "total_bytes",

    @rptmonth as "rpt_month"

    ----into ##top100temp

    from webproxylog''' + cast(month(dateadd(m,-2,getdate())) as varchar(2)) + '''

    --from webproxylog5

    where dbo.user_parser(clientusername) <> '' ''

    group by dbo.user_parser(clientusername)

    order by total_bytes desc'

    --print @tempsql

    execute (@tempsql)

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Checking your code, I found that you could make some improvements to it. But to help you, we'll need the definition of the webproxylog5 table and user_parser function. And some sample data will help as well.

    Meanwhile, you can change your first lines to avoid additional variables.

    'declare @rptmonth datetime

    select @rptmonth = DATEADD(MM, DATEDIFF(MM,0,GETDATE()) - 1, 0)

    '

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Hi Luis,

    Thank you very much for your suggesstion. With one change, your solution worked. I just had to make the following changes to the line containing the 'from' clause. Changed the triple ticks to single ticks. Here is the working script:

    use webproxy

    DECLARE @tempsql varchar(2000)

    select @tempsql =

    'declare @xmonth varchar(2)

    declare @xyear varchar(4)

    declare @xdate varchar(10)

    declare @rptmonth datetime

    select @xmonth = MONTH(dateadd(month,-1,getdate()))

    select @xyear = YEAR(dateadd(month,-1,getdate()))

    select @xdate = @xmonth + ''/01/'' + @xyear

    select @rptmonth = cast(@xdate as datetime)

    set rowcount 0

    select dbo.user_parser(clientusername) as "_user",

    count(*) as "objects",

    sum(cast(bytessent as float))as "bytes_sent",

    sum(cast(bytesrecvd as float))as "bytes_received",

    (sum(cast(bytessent as float)) + sum(cast(bytesrecvd as float)))as "total_bytes",

    @rptmonth as "rpt_month"

    ----into ##top100temp

    from webproxylog' + cast(month(dateadd(m,-2,getdate())) as varchar(2)) + '

    --from webproxylog5

    where dbo.user_parser(clientusername) <> '' ''

    group by dbo.user_parser(clientusername)

    order by total_bytes desc'

    --print @tempsql

    execute (@tempsql)

    By the way, how would I mark this post as 'RESOLVED', or 'CLOSED' or something like that?

    Thank you so much and continued success,

    Seyed

  • There's no way to mark it as solved or closed (unless you're an administrator).

    I will make emphasis on avoiding the use of functions in your queries. Your query won't be able to use indexes or multiple processors and that will have a huge impact on performance.

    Beware as well of float types, they can give inaccurate information and you should use decimal (or numeric). As bytes usually won't have decimal positions you could use int or bigint.

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Appreciate your inputs on how to make this code more efficient. I have inherited this code from someone who has retired. I will replace the float data types with int or bigint, and also will find a way to eliminate the need for calling these functions.

    Thanks again,

    Seyed

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply