Unable to use a variable in the @body parameter of sp_send_dbmail

  • I am trying to build a variable to be used with the @body parameter of sp_send_dbmail. Here is the code I am trying to run:

    DECLARE @v_body varchar(MAX)

    DECLARE @v_business_name varchar(75) = 'Hollies Gift Shop'

    DECLARE @v_owner_first_name varchar(30) = 'Bernice'

    DECLARE @v_owner_last_name varchar(30) = 'Goodly'

    DECLARE @v_profile varchar(30) = 'testprofile'

    set @v_body = 'Business Name: ' + @v_business_name + char(13) +char(10)

    + 'First Name : ' + @v_owner_first_name + char(13) +char(10)

    + 'Last Name : ' + @v_owner_first_name

    USE msdb

    GO

    EXEC sp_send_dbmail

    @profile_name = 'testprofile',

    @recipients = 'example@yahoo.com',

    @subject = 'Test message',

    @body = @v_body

    I receive the following error: Must declare the scalar variable "@v_body".

    What is it that I'm doing wrong

  • You have a GO after your USE statement. This terminates the batch above the GO, eliminating the variable declaration in the batch started immediately after the GO. Move the USE and GO above your declarations and all should be well.

    USE msdb

    GO

    DECLARE @v_body varchar(MAX)

    DECLARE @v_business_name varchar(75) = 'Hollies Gift Shop'

    DECLARE @v_owner_first_name varchar(30) = 'Bernice'

    DECLARE @v_owner_last_name varchar(30) = 'Goodly'

    DECLARE @v_profile varchar(30) = 'testprofile'

    set @v_body = 'Business Name: ' + @v_business_name + char(13) +char(10)

    + 'First Name : ' + @v_owner_first_name + char(13) +char(10)

    + 'Last Name : ' + @v_owner_first_name

    EXEC sp_send_dbmail

    @profile_name = 'testprofile',

    @recipients = 'example@yahoo.com',

    @subject = 'Test message',

    @body = @v_body;

    Another way is to EXECUTE msdb.dbo.sp_send_dbmail instead. I personally prefer this approach, but it's just a matter of preference.

  • Ed,

    Thank you so much for the help. It worked like a charm and once you explained what was wrong it made perfect sense.

Viewing 4 posts - 1 through 3 (of 3 total)

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