|
| 1 | + |
| 2 | +SET ANSI_NULLS ON |
| 3 | +GO |
| 4 | +SET QUOTED_IDENTIFIER ON |
| 5 | +GO |
| 6 | + |
| 7 | +/* |
| 8 | + Usage 1: |
| 9 | + DECLARE @lcHTML VARCHAR(MAX) |
| 10 | + EXEC dbo.spConvertTableData_to_HTML 'DBName', 'TableNAme', 'WHERE Criteria', '#FFA6D9', '#FFFFFF', '<B>Header</B>', '<B>Footer</B>', @lcHTML OUTPUT |
| 11 | + SELECT @lcHTML |
| 12 | +
|
| 13 | + Usage 2: |
| 14 | + DECLARE @lcHTML VARCHAR(MAX) |
| 15 | + EXEC dbo.spConvertTableData_to_HTML @argDatabaseName = 'tempdb', @argTableName = '#tmpResult', @argWHERE_Condition = '', |
| 16 | + @argColumnHeader_BackColor = '', @argColumnHeader_ForeColor = '', |
| 17 | + @argHeader_HTML = '', @argFooter_HTML = '', |
| 18 | + @argOutputData_HTML = @lcHTML OUTPUT; |
| 19 | +*/ |
| 20 | +CREATE OR ALTER PROCEDURE [dbo].[spConvertTableData_to_HTML] |
| 21 | + @argDatabaseName VARCHAR(128), @argTableName VARCHAR(128), @argWHERE_Condition VARCHAR(MAX), |
| 22 | + @argColumnHeader_BackColor VARCHAR(20), @argColumnHeader_ForeColor VARCHAR(20), |
| 23 | + @argHeader_HTML VARCHAR(MAX), @argFooter_HTML VARCHAR(MAX), @argOutputData_HTML VARCHAR(MAX) OUTPUT |
| 24 | +AS |
| 25 | +BEGIN |
| 26 | + SET NOCOUNT ON; |
| 27 | + |
| 28 | + DECLARE @lcSQL NVARCHAR(1000); |
| 29 | + |
| 30 | + IF ISNULL(@argColumnHeader_BackColor, '') = '' |
| 31 | + SET @argColumnHeader_BackColor = '#A6A6D9' |
| 32 | + |
| 33 | + IF ISNULL(@argColumnHeader_ForeColor, '') = '' |
| 34 | + SET @argColumnHeader_ForeColor = '#000000' |
| 35 | + |
| 36 | + -- Table Columns |
| 37 | + CREATE TABLE #TableColumns (ColumnName VARCHAR(128)) |
| 38 | + SET @lcSQL = 'SELECT C.name FROM [' + @argDatabaseName + '].sys.columns C WHERE C.object_id=object_id(''' + @argDatabaseName + '..' + @argTableName + ''')' |
| 39 | + |
| 40 | + INSERT INTO #TableColumns |
| 41 | + EXEC (@lcSQL) |
| 42 | + |
| 43 | + -- Column Header |
| 44 | + DECLARE @lcColumnHeaderHTML NVARCHAR(MAX), @lcColumns NVARCHAR(MAX), @lcColumnDataSQL NVARCHAR(MAX), @lcColumnDataHTML NVARCHAR(MAX) |
| 45 | + SET @lcColumnHeaderHTML = (SELECT '<th> ' + C.ColumnName + ' </th> ' |
| 46 | + FROM #TableColumns C |
| 47 | + FOR XML PATH(''), TYPE).value('.','VARCHAR(MAX)') |
| 48 | + --Column Value |
| 49 | + SET @lcColumns = STUFF((SELECT ', '''', ISNULL(CONVERT(VARCHAR(MAX), [' + C.ColumnName + ']), '''') AS ''td'' ' |
| 50 | + FROM #TableColumns C |
| 51 | + FOR XML PATH(''), TYPE).value('.','VARCHAR(MAX)'), 1, 5, '') |
| 52 | + SET @lcColumnDataSQL = 'SET @lcColumnDataHTML = CAST((SELECT ' + @lcColumns + ' |
| 53 | + FROM ' + IIF(@argDatabaseName='tempdb', '', @argDatabaseName + '..') + @argTableName + ' |
| 54 | + ' + ISNULL(@argWHERE_Condition, '') + ' |
| 55 | + FOR XML PATH(''tr''), TYPE, ELEMENTS) AS NVARCHAR(MAX))' |
| 56 | + |
| 57 | + --PRINT @lcColumnDataSQL |
| 58 | + EXEC sp_executesql @lcColumnDataSQL, N'@lcColumnDataHTML NVARCHAR(MAX) OUTPUT', @lcColumnDataHTML OUTPUT |
| 59 | + |
| 60 | + |
| 61 | + SET @argOutputData_HTML ='<HTML><BODY> ' + ISNULL(@argHeader_HTML, '') + ' |
| 62 | + <TABLE border=1 bordercolor=' + @argColumnHeader_BackColor + ' style="font-family:Tahoma; font-size:10pt"> |
| 63 | + <TR style="background-color:' + @argColumnHeader_BackColor + '; color:' + @argColumnHeader_ForeColor + '">' + @lcColumnHeaderHTML + '</tr>' |
| 64 | + |
| 65 | + |
| 66 | + SET @argOutputData_HTML = @argOutputData_HTML + ISNULL(@lcColumnDataHTML,'') + '</TABLE> ' + |
| 67 | + ISNULL(@argFooter_HTML, '') + '</BODY></HTML>' |
| 68 | +END |
0 commit comments