SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Trying to convert the result set into HTML format but have problem with XML column


Trying to convert the result set into HTML format but have problem with XML column

Author
Message
veerbharat_jaiswal86
veerbharat_jaiswal86
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 179
Hello everyone,
Being new to XML i have stuck in the middle of no where while converting the result set of my sql query in HTML format, getting all the data as per the expectation but somehow the XML column is blank in the HTML..
Have a look at the code below...


DECLARE @txtMis VARCHAR(Max)--,

SET @txtMis = '<HTML><Head><meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<title>Untitled Document</title><style type="text/css">
body {
margin: 0px;
padding:25px;
font-family:Arial, Helvetica, sans-serif;
font-size:12px;
color:#454545;
}
</style>
</head>

<BODY bgColor="FFFFFF">'
SET @txtMis = @txtMis
+ '<table width="100%" border="0" cellspacing="0" cellpadding="0" style="border:solid 1px #d5d5d5; border-right:0px none; border-bottom:0px none font-size: 8px;">
<tr>
<td colspan="10" align="center" bgcolor="#f8f8f8" height="28" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;"><b>Details of Missing Index on
</b></td>
</tr>
<tr>
<td bgcolor="#f8f8f8" height="28" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">MissingIndexesPortion</td>
<td bgcolor="#f8f8f8" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">DatabaseName</td>

<td bgcolor="#f8f8f8" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">ObjectName</td>
<td bgcolor="#f8f8f8" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">SizeBytes</td>
<td bgcolor="#f8f8f8" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">CacheObjectType</td>
</tr>'
;WITH
XMLNAMESPACES
(
DEFAULT 'http://schemas.microsoft.com/sqlserver/2004/07/showplan'
)
, CachedPlans
(
MissingIndexesPortion ,
DatabaseName,
ObjectName,
SizeBytes,
CacheObjectType
)
AS
(
SELECT
CAST(RelOp.op.query('.') AS varchar(max)) AS MissingIndexesPortion,
Db_name(qp.dbid),

Object_name (qp.objectid,qp.dbid),
cp.size_in_bytes AS SizeBytes,
cp.cacheobjtype AS CacheObjectType
FROM
sys.dm_exec_cached_plans cp
CROSS APPLY
sys.Dm_exec_sql_text(cp.plan_handle) st
CROSS APPLY
sys.Dm_exec_query_plan(cp.plan_handle) qp
CROSS APPLY
qp.query_plan.nodes('//MissingIndexes') RelOp (op)
)
SELECT @txtMis = @txtMis
+ '<tr>
<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">'
+ ISNULL(MissingIndexesPortion, '')
+ '</td>'
+ '<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">'
+ ISNULL(DatabaseName, '')
+ '</td>'

+ '<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">'
+ ISNULL(procedurename, '')
+ '</td>'
+ '<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">'
+ ISNULL(SizeBytes, '') + '</td>'
+ '<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">'
+ ISNULL(CacheObjectType, '') + '</td>
</tr>'
FROM (
SELECT
MissingIndexesPortion AS MissingIndexesPortion ,
CONVERT(VARCHAR(5000),DatabaseName) AS DatabaseName,
CONVERT(VARCHAR(5000),ObjectName) AS procedurename,
CONVERT(VARCHAR(5000),SizeBytes) AS SizeBytes,
CONVERT(VARCHAR(5000),CacheObjectType) AS CacheObjectType
FROM
CachedPlans
WHERE CacheObjectType = 'Compiled Plan'
) v
ORDER BY
v.SizeBytes DESC
SELECT @txtMis = @txtMis + '</table>
</body>
</html>'
SELECT @txtMis

Any help would be appreciated
Steven Willis
Steven Willis
SSC Eights!
SSC Eights! (821 reputation)SSC Eights! (821 reputation)SSC Eights! (821 reputation)SSC Eights! (821 reputation)SSC Eights! (821 reputation)SSC Eights! (821 reputation)SSC Eights! (821 reputation)SSC Eights! (821 reputation)

Group: General Forum Members
Points: 821 Visits: 1721
I tried and failed to run a query that would produce the "Missing Index" option, so I can't confirm that the code below does exactly what you are looking for. It does find and parse the query plan XML for queries in the cache and produces HTML code from that. I had to change a lot of things to get it to do anything for me, so I hope this can at least point you in the right direction.



IF OBJECT_ID('tempdb..#TempTable') IS NOT NULL
DROP TABLE #TempTable

CREATE TABLE #TempTable (
[ID] INT IDENTITY(1,1) NOT NULL,
[MissingIndex] VARCHAR(8000) NULL,
[DatabaseName] VARCHAR(50) NULL,
[SizeBytes] INT NULL,
[CacheObjectType] VARCHAR(50) NULL,
[ObjectDetail] VARCHAR(MAX) NULL,
[BatchXML] XML NULL,
PRIMARY KEY (ID),
UNIQUE (ID))

DECLARE
@txtMis VARCHAR(MAX)

SET @txtMis = '<HTML><Head><meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<title>Untitled Document</title><style type="text/css">
body {
margin: 0px;
padding:25px;
font-family:Arial, Helvetica, sans-serif;
font-size:12px;
color:#454545;
}
</style>
</head>
<BODY bgColor="FFFFFF">'

SET @txtMis = @txtMis + '<table width="100%" border="0" cellspacing="0" cellpadding="0" style="border:solid 1px #d5d5d5; border-right:0px none; border-bottom:0px none font-size: 8px;">
<tr>
<td colspan="10" align="center" bgcolor="#f8f8f8" height="28" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;"><b>Details of Missing Index on
</b></td>
</tr>
<tr>
<td bgcolor="#f8f8f8" height="28" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">MissingIndex</td>
<td bgcolor="#f8f8f8" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">DatabaseName</td>
<td bgcolor="#f8f8f8" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">SizeBytes</td>
<td bgcolor="#f8f8f8" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">CacheObjectType</td>
<td bgcolor="#f8f8f8" style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">ObjectDetail</td>
</tr>'

;WITH CachedPlans
(
MissingIndex,
DatabaseName,
SizeBytes,
CacheObjectType,
ObjectDetail,
BatchXML
)
AS
(
SELECT
objDatabase+'.'+ObjSchema+'.'+objTable+':'+objColGroupUsage+'.'+ObjColname+'.'+ObjColColumnID AS MissingIndex
,r.DatabaseName
,r.SizeBytes
,r.CacheObjectType
,r.objQueryPlan AS ObjectDetail
,r.q AS BatchXML
FROM
(
SELECT
x.q.value('(BatchSequence/Batch/Statements/StmtSimple/QueryPlan/MissingIndexes/MissingIndexGroup/MissingIndex/@Database)[1]','VARCHAR(50)') AS objDatabase
,x.q.value('(BatchSequence/Batch/Statements/StmtSimple/QueryPlan/MissingIndexes/MissingIndexGroup/MissingIndex/@Schema)[1]','VARCHAR(50)') AS objSchema
,x.q.value('(BatchSequence/Batch/Statements/StmtSimple/QueryPlan/MissingIndexes/MissingIndexGroup/MissingIndex/@Table)[1]','VARCHAR(100)') AS objTable
,x.q.value('(BatchSequence/Batch/Statements/StmtSimple/QueryPlan/MissingIndexes/MissingIndexGroup/MissingIndex/ColumnGroup/@Usage)[1]','VARCHAR(100)') AS objColGroupUsage
,x.q.value('(BatchSequence/Batch/Statements/StmtSimple/QueryPlan/MissingIndexes/MissingIndexGroup/MissingIndex/ColumnGroup/Column/@Name)[1]','VARCHAR(100)') AS objColName
,x.q.value('(BatchSequence/Batch/Statements/StmtSimple/QueryPlan/MissingIndexes/MissingIndexGroup/MissingIndex/ColumnGroup/Column/@ColumnId)[1]','VARCHAR(100)') AS objColColumnId
,x.q.value('(BatchSequence/Batch/Statements/StmtSimple/@StatementText)[1]','VARCHAR(MAX)') AS objQueryPlan
,x.*
FROM
(
SELECT
DB_NAME(st.dbid) AS DatabaseName
,cp.size_in_bytes AS SizeBytes
,cp.cacheobjtype AS CacheObjectType
,cp.plan_handle
,CONVERT(XML,REPLACE(REPLACE(CAST(qp.query_plan AS VARCHAR(MAX)),'<ShowPlanXML xmlns="http://schemas.microsoft.com/sqlserver/2004/07/showplan" Version="1.1.1" Build="10.0.5512.0">',''),'</ShowPlanXML>','')) AS q
FROM
sys.dm_exec_cached_plans cp
CROSS APPLY
sys.Dm_exec_sql_text(CONVERT(VARBINARY,cp.plan_handle)) st
CROSS APPLY
sys.Dm_exec_query_plan(CONVERT(VARBINARY,cp.plan_handle)) qp
) x
) r
WHERE
CacheObjectType = 'Compiled Plan'
)
INSERT INTO #TempTable
SELECT
MissingIndex
,DatabaseName
,SizeBytes
,CacheObjectType
,ObjectDetail
,BatchXML
FROM
CachedPlans


SELECT
@txtMis = @txtMis + '<tr>
<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">' + ISNULL(MissingIndex,'') + '</td>' + '<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">' + ISNULL(DatabaseName,'') + '</td>' + '<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">' + ISNULL(ObjectDetail,'') + '</td>' + '<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">' + ISNULL(SizeBytes,'') + '</td>' + '<td style="border-bottom:#d5d5d5 solid 1px; border-right:#d5d5d5 solid 1px;">' + ISNULL(CacheObjectType,'') + '</td>
</tr>'
FROM
(
SELECT
MissingIndex AS MissingIndex
,CONVERT(VARCHAR(50),DatabaseName) AS DatabaseName
,CONVERT(VARCHAR(50),SizeBytes) AS SizeBytes
,CONVERT(VARCHAR(50),CacheObjectType) AS CacheObjectType
,CONVERT(VARCHAR(MAX),ObjectDetail) AS ObjectDetail
FROM
#TempTable
) v
ORDER BY
v.SizeBytes DESC
SELECT
@txtMis = @txtMis + '</table>
</body>
</html>'

SELECT
@txtMis





 
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search