Email Formatted HTML Table with T-SQL

  • Comments posted to this topic are about the item Email Formatted HTML Table with T-SQL

  • I don't believe you'll find anyone more pro-xp_CmdShell or pro_BCP than myself but I can't figure out why you bothered with either for this task since sp_SendDBMail could have easily handled this task. And having to install a 3rd party piece of shareware on a server certainly doesn't make for a "T-SQL Only" project, IMHO.

    Why didn't you just use sp_SendDBMail which can take a 2GB VARCHAR(MAX) body with the custom HTML formatting from your article?

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff Moden (6/19/2013)


    I don't believe you'll find anyone more pro-xp_CmdShell or pro_BCP than myself but I can't figure out why you bothered with either for this task since sp_SendDBMail could have easily handled this task. And having to install a 3rd party piece of shareware on a server certainly doesn't make for a "T-SQL Only" project, IMHO.

    Why didn't you just use sp_SendDBMail which can take a 2GB VARCHAR(MAX) body with the custom HTML formatting from your article?

    Thanks for the feedback Jeff!

    Basically, I think you are right. I should have written the article with a more modern twist. The practical reason is that I wear many different hats so I end up using Blat for SysAdmin tasks, AD notifications, sending log files, etc. And I was using Blat with SQL Server 7.0. It is just an old habit that works so I haven't changed it.

  • Hey,

    This is a Email Formatted HTML table i like to use,..

    im sure it would be usefull and easy to use as it is for me 🙂

    -------------------------------------------------------------------------

    -- Email Querry--

    DECLARE @Body varchar(max)

    declare @TableHead varchar(max)

    declare @TableTail varchar(max)

    declare @mailitem_id as int

    declare@statusMsg as varchar(max)

    declare@Error as varchar(max)

    declare@Note as varchar(max)

    Set NoCount On;

    set @mailitem_id = null

    set @statusMsg = null

    set @Error = null

    set @Note = null

    Set @TableTail = '</table></body></html>';

    --HTML layout--

    Set @TableHead = '<html><head>' +

    '<H1 style="color: #000000">HEADER OF TABLE</H1>' +

    '<style>' +

    'td {border: solid black 1px;padding-left:5px;padding-right:5px;padding-top:1px;padding-bottom:1px;font-size:9pt;color:Black;} ' +

    '</style>' +

    '</head>' +

    '<body><table cellpadding=0 cellspacing=0 border=0>' +

    '<tr bgcolor=#F6AC5D>'+

    '<td align=center><b>Name of column</b></td>' +

    '<td align=center><b>Name of column</b></td>' +

    '<td align=center><b>Name of column</b></td>' +

    '<td align=center><b>Name of column</b></td>' +

    '<td align=center><b>Name of column</b></td></tr>';

    --Select information for the Report--

    Select @Body= (Select

    Column As

    ,

    Column As

    ,

    Column As

    ,

    Column As

    ,

    Column As

    FROM [DB].[dbo].[Table]

    where -condition-

    (whatever you want to do else ...)

    For XML raw('tr'), Elements)

    -- Replace the entity codes and row numbers

    Set @Body = Replace(@Body, '_x0020_', space(1))

    Set @Body = Replace(@Body, '_x003D_', '=')

    Set @Body = Replace(@Body, '<tr><TRRow>1</TRRow>', '<tr bgcolor=#C6CFFF>')

    Set @Body = Replace(@Body, '<TRRow>0</TRRow>', '')

    Set @Body = @TableHead + @Body + @TableTail

    -- return output--

    Select @Body

    --Email

    EXEC msdb.dbo.sp_send_dbmail

    @profile_name =email', <--This is the mail account to sent from.

    @mailitem_id = @mailitem_id out,

    @recipients='blah@blah.co.za',

    @subject = 'subject Email',

    @body = @Body,

    @body_format = 'HTML';

  • Why not using CSS?

    Example:

    DECLARE @bodyMsg nvarchar(max)

    DECLARE @subject nvarchar(max)

    DECLARE @tableHTML nvarchar(max)

    SET @subject = 'Query Results in HTML with CSS'

    SET @tableHTML =

    N'<style type="text/css">

    #box-table

    {

    font-family: "Lucida Sans Unicode", "Lucida Grande", Sans-Serif;

    font-size: 12px;

    text-align: center;

    border-collapse: collapse;

    border-top: 7px solid #9baff1;

    border-bottom: 7px solid #9baff1;

    }

    #box-table th

    {

    font-size: 13px;

    font-weight: normal;

    background: #b9c9fe;

    border-right: 2px solid #9baff1;

    border-left: 2px solid #9baff1;

    border-bottom: 2px solid #9baff1;

    color: #039;

    }

    #box-table td

    {

    border-right: 1px solid #aabcfe;

    border-left: 1px solid #aabcfe;

    border-bottom: 1px solid #aabcfe;

    color: #669;

    }

    tr:nth-child(odd){ background-color:#eee; }

    tr:nth-child(even){ background-color:#fff; }

    </style>'+

    N'<H3><font color="Red">All Rows From [AdventureWorks].[Sales].[SpecialOffer]</H3>' +

    N'<table id="box-table" >' +

    N'<tr><font color="Green"><th>SpecialOfferID</th>

    <th>Description</th>

    <th>Type</th>

    <th>Category</th>

    <th>StartDate</th>

    <th>EndDate</th>

    </tr>' +

    CAST ( (

    SELECT td = CAST([SpecialOfferID] AS VARCHAR(100)),'',

    td = [Description],'',

    td = [Type],'',

    td = [Category] ,'',

    td = CONVERT(VARCHAR(30),[StartDate],120) ,'',

    td = CONVERT(VARCHAR(30),[EndDate],120)

    FROM [AdventureWorks].[Sales].[SpecialOffer]

    ORDER BY [SpecialOfferID]

    FOR XML PATH('tr'), TYPE

    ) AS NVARCHAR(MAX) ) +

    N'</table>'

    EXEC msdb.dbo.sp_send_dbmail @recipients='AnyMailYouWant@SqlIsCool.com',

    @subject = @subject,

    @body = @tableHTML,

    @body_format = 'HTML' ;

    Result:

  • OH Nice !! .. that does look way better...

    At the moment my preview only has a colored background for the Clolumn header

    As seen in my Attachment (Dont know if you will be able to see it)

  • Does that work in Gmail? I recall having an issue putting the <head> tag in the body of the email, so I couldn't use CSS. Although I wanted to.

  • No Need to put <head> tag 🙂 this is a In-Line CSS in the <body> of the HTML...

    BUT Gmail is striping any Style (CSS) out of the HTML... 🙁

    i will try to make it work in Gmail... googling....

  • The one i wrote works for gmail as well, its just a straight forward HTML Email format with no fansy addons.

    Its a good alternative if you run into compatability problems.

    Keep it simple ...

  • i fixed my code to support the "problematic" gmail which strips any CSS styling...

    and as you say "keep it simple" , so NO bcp, NO xp_cmdshell ,NO Blat = ONLY TSQL 🙂

    DECLARE @bodyMsg nvarchar(max)

    DECLARE @subject nvarchar(max)

    DECLARE @tableHTML nvarchar(max)

    DECLARE @Table NVARCHAR(MAX) = N''

    SET @subject = 'Query Results in HTML with CSS'

    SELECT @Table = @Table +'<tr style="background-color:'+CASE WHEN (ROW_NUMBER() OVER (ORDER BY [SpecialOfferID]))%2 =1 THEN '#A3E0FF' ELSE '#8ED1FB' END +';">' +

    '<td>' + CAST([SpecialOfferID] AS VARCHAR(100))+ '</td>' +

    '<td>' + [Description]+ '</td>' +

    '<td>' + [Type]+ '</td>' +

    '<td>' + [Category] + '</td>' +

    '<td>' + CONVERT(VARCHAR(30),[StartDate],120) + '</td>' +

    '<td>' + CONVERT(VARCHAR(30),[EndDate],120) + '</td>' +

    '</tr>'

    FROM [dbo].[SpecialOffer]

    ORDER BY [SpecialOfferID]

    SET @tableHTML =

    N'<H3><font color="Red">All Rows From [AdventureWorks].[Sales].[SpecialOffer]</H3>' +

    N'<table border="1" align="center" cellpadding="2" cellspacing="0" style="color:purple;font-family:arial,helvetica,sans-serif;text-align:center;" >' +

    N'<tr style ="font-size: 14px;font-weight: normal;background: #b9c9fe;">

    <th>SpecialOfferID</th>

    <th>Description</th>

    <th>Type</th>

    <th>Category</th>

    <th>StartDate</th>

    <th>EndDate</th></tr>' + @Table +N'</table>'

    EXEC msdb.dbo.sp_send_dbmail @recipients='AnyEmail@SqlIsCool.com',

    @subject = @subject,

    @body = @tableHTML,

    @body_format = 'HTML' ;

    Result in Gmail:

  • Does this work when those e-mails are opened using outlook 2007 or later versions?

  • This subject is very dear to my heart - I had to do so many projects that send emails to customers. One thing I always do is create HTML templates with my own tags inside. I usually have one template for the body and second for the line. This gives me ability to have multiple versions of the same email in different languages for example. Then at run time, driven by data I select appropriate template with a series of simple replace statements plug in data in place of my tags. and send it out.

    I remember one project were I had 10 variations of email in 3 different languages, 30 total and was all handled in one procedure.

  • I've never had a problem with any of the email clients. Simple HTML is recognized by all of them.

  • Are we solving the problem right?

    Are we solving the right problem?

    Jeff asked why use xp_cmdshell to get to a third-party tool & suggested db_sendmail: depending on your environment, the answer to that first question is either "No" or "Right enough" 🙂

    I wonder if composing html <table>s and emailing them is the right way to share content.

    (aside from the pretty/ugly formatting of inline style workarounds for various capabilities of mail client(s) such as gmail stripping style tags and even inline attributes google decided aren't appropriate for your email or Outlook 2007/2010 using Word to render emails)

    If the data is meant to be further consumed, the html table is somewhat klunky. If the data is meant to be looked at, there is too much requirement for 'pretty' to make emailed tables a robust solution. If the data is meant to be proof that something else happened, does it need to provide so much detail (and cost the overhead to get all that detail, formatted, etc.)?

    If the data were staged for consumption by a data-query in Excel (for example) the analyst using it would be able to easily further transform via charting/pivoting/filtering, etc. If reporting services (either MS, or 3rd party such as Crystal Reports/Crystal Solutions) generates the 'pretty' version to a PDF - that could be mailed/attached/referenced. Another option might be to simply render the data to html via a web service: properly executed CSS can make a nice view for direct human eyes-on or the semantically correct table can be consumed by Excel's html table import (or googledocs html scraping equivalent)

    Another consideration is the amount of content we _can_ get from a query may be much more than we _should_ put in an email. I know, nobody intends to put 30k rows of data in an email... When we built and tested there was only 200 rows in the table... 3 years later we're causing grief to the email administrator when we're storing an html version of the day's snapshot in 12 email recipient's inbox. (and 10 of those recipients keep everything we've ever mailed in "archive" folders on the email server) I'm not sure if this qualifies as Database Backup, but you can see how well it scales. 🙂

  • SQL-DBA (6/20/2013)


    Jeff Moden (6/19/2013)


    I don't believe you'll find anyone more pro-xp_CmdShell or pro_BCP than myself but I can't figure out why you bothered with either for this task since sp_SendDBMail could have easily handled this task. And having to install a 3rd party piece of shareware on a server certainly doesn't make for a "T-SQL Only" project, IMHO.

    Why didn't you just use sp_SendDBMail which can take a 2GB VARCHAR(MAX) body with the custom HTML formatting from your article?

    Thanks for the feedback Jeff!

    Basically, I think you are right. I should have written the article with a more modern twist. The practical reason is that I wear many different hats so I end up using Blat for SysAdmin tasks, AD notifications, sending log files, etc. And I was using Blat with SQL Server 7.0. It is just an old habit that works so I haven't changed it.

    Ah! I get that. Thanks, for the feedback, Steve. I still use CDOSYS for my DBA emails for couple of reasons not the least of which is that sp_SendDBMail didn't allow for a specific FROM (fixed in 2012, IIRC) without taking the time to setup a different profile. I also work on servers that don't (and won't for one reason or another) have email setup where it comes in might handy for the generation of "Morning Reports" on the server status.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 15 posts - 1 through 15 (of 82 total)

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