February 10, 2014 at 5:46 am
Hello all
I am trying to get data from an xml file and I cannot figure out what's wrong. Can you please help me with a piece of code. the xml file looks like this:
<Row ss:StyleID="s63">
<Cell><Data ss:Type="String">xxxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxxxx</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx</Data></Cell>
</Row>
<row>
.....................
</row>
.............
the path to this rows is: /workbook/worksheet/table/row
from each row, I want to get only the first 4 columns.
February 10, 2014 at 9:20 am
It will be helpful if you attach / post a workable document.
In the meantime here is an example that can help you.
SET NOCOUNT ON;
USE tempdb;
GO
DECLARE @x xml = '
<Table xmlns:ss="uri">
<Row ss:StyleID="s63" ID="1">
<Cell><Data ss:Type="String">xxxxxxxxx-1</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-2</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-3</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxxx-4</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-5</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxx-6</Data></Cell>
<Cell><Data ss:Type="String">xxxxxx-7</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxx-8</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-9</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-10</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxxxx-11</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxxxx-12</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-13</Data></Cell>
</Row>
<Row ss:StyleID="s63" ID="2">
<Cell><Data ss:Type="String">xxxxxxxx-1</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-2</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-3</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-4</Data></Cell>
<Cell><Data ss:Type="String">xxxxxxxx-5</Data></Cell>
</Row>
</Table>';
WITH XMLNAMESPACES ('uri' AS ss)
,C1 AS (
SELECT
n1.r.value('@ID[1]', 'int') AS RID,
n2.d.value('text()[1]', 'varchar(128)') AS val,
ROW_NUMBER() OVER(PARTITION BY n1.r ORDER BY n2.d) AS rn
FROM
@x.nodes('Table/Row') AS n1(r)
CROSS APPLY
n1.r.nodes('Cell/Data') AS n2(d)
)
SELECT
RID,
val
FROM
C1
WHERE
rn < 5
ORDER BY
RID,
rn;
GO
February 11, 2014 at 12:29 am
Thank you for the answer, but it's not exactly how I need it. As for the xml file, I cannot do anything. I see that you used an ID for each row. I cannot use that. and the final display should look like this:
row1: col1 col2 col3 col4
row2: col1 col2 col3 col4
.............
I will prepare a document for upload
February 11, 2014 at 12:50 am
here is the file. so the result should look like this:
Hostname DBInstanceName DatabaseName
host1 instance 1 db1
host1 instance1 db2
host2 instance2 db1
host2 instance2 db2
from each <row> ....</row> I want the first 3 datacells
*please change the file extension. I am not allowed to upload as xml so I made it .txt
February 11, 2014 at 10:30 am
You are interested in pivoting the values for all nodes positioned at specific number. If we extract the text an enumerate the rows then the numbers greater 4, 5 and 6 correspond to (Hostname, DBInstanceName, DatabaseName) and you have a block every 13 rows.
We have to identify the blocks "(rn - 1) / 13" and pivot the data.
SET NOCOUNT ON;
USE tempdb;
GO
DECLARE @x xml = N'<?xml version="1.0"?>
<?mso-application progid="Excel.Sheet"?>
<Workbook xmlns="urn:schemas-microsoft-com:office:spreadsheet"
xmlns:o="urn:schemas-microsoft-com:office:office"
xmlns:x="urn:schemas-microsoft-com:office:excel"
xmlns:ss="urn:schemas-microsoft-com:office:spreadsheet"
xmlns:html="http://www.w3.org/TR/REC-html40">
<DocumentProperties xmlns="urn:schemas-microsoft-com:office:office">
<Author>Author_of_XML</Author>
<LastAuthor>Author_of_XML</LastAuthor>
<Version>1.00</Version>
</DocumentProperties>
<OfficeDocumentSettings xmlns="urn:schemas-microsoft-com:office:office">
<DownloadComponents/>
<LocationOfComponents HRef="/"/>
</OfficeDocumentSettings>
<ExcelWorkbook xmlns="urn:schemas-microsoft-com:office:excel">
<WindowHeight>13020</WindowHeight>
<WindowWidth>28800</WindowWidth>
<WindowTopX>0</WindowTopX>
<WindowTopY>0</WindowTopY>
<ProtectStructure>False</ProtectStructure>
<ProtectWindows>False</ProtectWindows>
</ExcelWorkbook>
<Styles>
<Style ss:ID="Default" ss:Name="Normal">
<Alignment ss:Vertical="Bottom"/>
<Borders/>
<Font ss:FontName="Arial"/>
<Interior ss:Color="gray" ss:Pattern="Solid"/>
<NumberFormat/>
<Protection/>
</Style>
<Style ss:ID="s63" ss:Name="TableHeader">
<Borders>
<Border ss:Position="Bottom" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#990000"/>
<Border ss:Position="Left" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#990000"/>
<Border ss:Position="Right" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#990000"/>
<Border ss:Position="Top" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#990000"/>
</Borders>
<Font ss:FontName="Arial" ss:Color="#000000" ss:Bold="1"/>
<Interior ss:Color="#EADEC2" ss:Pattern="Solid"/>
</Style>
<Style ss:ID="s64" ss:Name="TableValues">
<Borders>
<Border ss:Position="Bottom" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#000000"/>
<Border ss:Position="Left" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#000000"/>
<Border ss:Position="Right" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#000000"/>
<Border ss:Position="Top" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#000000"/>
</Borders>
<Font ss:FontName="Arial"/>
<Interior ss:Color="#F9F9F9" ss:Pattern="Solid"/>
</Style>
<Style ss:ID="s62" ss:Name="TopHeader">
<Alignment ss:Vertical="Center"/>
<Borders>
<Border ss:Position="Left" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#FFFFFF"/>
<Border ss:Position="Right" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#FFFFFF"/>
</Borders>
<Font ss:FontName="Arial" ss:Color="#FFFFFF" ss:Bold="1"/>
<Interior ss:Color="#990000" ss:Pattern="Solid"/>
</Style>
<Style ss:ID="m206143808" ss:Parent="s62">
<Alignment ss:Vertical="Center"/>
<Borders>
<Border ss:Position="Left" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#FFFFFF"/>
<Border ss:Position="Right" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#FFFFFF"/>
</Borders>
<Font ss:FontName="Arial" ss:Color="#FFFFFF" ss:Bold="1"/>
<Interior ss:Color="#990000" ss:Pattern="Solid"/>
</Style>
<Style ss:ID="m206143828" ss:Parent="s62">
<Alignment ss:Vertical="Center"/>
<Borders>
<Border ss:Position="Left" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#FFFFFF"/>
<Border ss:Position="Right" ss:LineStyle="Continuous" ss:Weight="1"
ss:Color="#FFFFFF"/>
</Borders>
<Font ss:FontName="Arial" ss:Color="#FFFFFF" ss:Bold="1"/>
<Interior ss:Color="#990000" ss:Pattern="Solid"/>
</Style>
</Styles>
<Worksheet ss:Name="DatabaseInfo">
<Table ss:ExpandedColumnCount="15" x:FullColumns="1" x:FullRows="1">
<ss:Column ss:AutoFitWidth="1" ss:Width="60"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="72"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="126"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="108"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="54"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="81"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="72"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="72"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="63"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="63"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="90"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="81"/>
<ss:Column ss:AutoFitWidth="1" ss:Width="108"/>
<Row ss:AutoFitHeight="0" ss:Height="20.0625" ss:StyleID="s62">
<Cell ss:MergeAcross="14" ss:StyleID="m206143808"><Data ss:Type="String">Database Info</Data></Cell>
</Row>
<Row ss:AutoFitHeight="0" ss:Height="20.0625" ss:StyleID="s62">
<Cell ss:MergeAcross="14" ss:StyleID="m206143828"><Data ss:Type="String">Generated by ...... on ......</Data></Cell>
</Row>
<Row ss:StyleID="s63">
<Cell><Data ss:Type="String">DatabaseID</Data></Cell>
<Cell><Data ss:Type="String">Hostname</Data></Cell>
<Cell><Data ss:Type="String">DBInstanceName</Data></Cell>
<Cell><Data ss:Type="String">DatabaseName</Data></Cell>
<Cell><Data ss:Type="String">Status</Data></Cell>
<Cell><Data ss:Type="String">Collation</Data></Cell>
<Cell><Data ss:Type="String">Recovery</Data></Cell>
<Cell><Data ss:Type="String">TotalMBs</Data></Cell>
<Cell><Data ss:Type="String">UsedMBs</Data></Cell>
<Cell><Data ss:Type="String">FreeMBs</Data></Cell>
<Cell><Data ss:Type="String">LogSizeMBs</Data></Cell>
<Cell><Data ss:Type="String">LogUsage%</Data></Cell>
<Cell><Data ss:Type="String">LastScanTime</Data></Cell>
</Row>
<Row ss:StyleID="s64">
<Cell><Data ss:Type="Number">12</Data></Cell>
<Cell><Data ss:Type="String">Hostname1</Data></Cell>
<Cell><Data ss:Type="String">Instancename1</Data></Cell>
<Cell><Data ss:Type="String">database1</Data></Cell>
<Cell><Data ss:Type="String">ONLINE</Data></Cell>
<Cell><Data ss:Type="String">Latin1_General_CI_AS</Data></Cell>
<Cell><Data ss:Type="String">SIMPLE</Data></Cell>
<Cell><Data ss:Type="String">4.44</Data></Cell>
<Cell><Data ss:Type="String">4.06</Data></Cell>
<Cell><Data ss:Type="String">0.38</Data></Cell>
<Cell><Data ss:Type="String">1.49</Data></Cell>
<Cell><Data ss:Type="String">45.55</Data></Cell>
<Cell><Data ss:Type="String">10/02/2012 07:43:26</Data></Cell>
</Row>
<Row ss:StyleID="s64">
<Cell><Data ss:Type="Number">13</Data></Cell>
<Cell><Data ss:Type="String">Hostname1</Data></Cell>
<Cell><Data ss:Type="String">Instancename1</Data></Cell>
<Cell><Data ss:Type="String">Database2</Data></Cell>
<Cell><Data ss:Type="String">ONLINE</Data></Cell>
<Cell><Data ss:Type="String">Latin1_General_CI_AS</Data></Cell>
<Cell><Data ss:Type="String">SIMPLE</Data></Cell>
<Cell><Data ss:Type="String">406.63</Data></Cell>
<Cell><Data ss:Type="String">10.5</Data></Cell>
<Cell><Data ss:Type="String">396.13</Data></Cell>
<Cell><Data ss:Type="String">611.12</Data></Cell>
<Cell><Data ss:Type="String">13.42</Data></Cell>
<Cell><Data ss:Type="String">10/02/2012 07:43:26</Data></Cell>
</Row>
<Row ss:StyleID="s64">
<Cell><Data ss:Type="Number">14</Data></Cell>
<Cell><Data ss:Type="String">Hostname2</Data></Cell>
<Cell><Data ss:Type="String">Instancename2</Data></Cell>
<Cell><Data ss:Type="String">database1</Data></Cell>
<Cell><Data ss:Type="String">ONLINE</Data></Cell>
<Cell><Data ss:Type="String">Latin1_General_CI_AS</Data></Cell>
<Cell><Data ss:Type="String">FULL</Data></Cell>
<Cell><Data ss:Type="String">2.19</Data></Cell>
<Cell><Data ss:Type="String">1.38</Data></Cell>
<Cell><Data ss:Type="String">0.81</Data></Cell>
<Cell><Data ss:Type="String">2.49</Data></Cell>
<Cell><Data ss:Type="String">37.93</Data></Cell>
<Cell><Data ss:Type="String">10/02/2012 07:43:26</Data></Cell>
</Row>
<Row ss:StyleID="s64">
<Cell><Data ss:Type="Number">14</Data></Cell>
<Cell><Data ss:Type="String">Hostname2</Data></Cell>
<Cell><Data ss:Type="String">Instancename2</Data></Cell>
<Cell><Data ss:Type="String">database2</Data></Cell>
<Cell><Data ss:Type="String">ONLINE</Data></Cell>
<Cell><Data ss:Type="String">Latin1_General_CI_AS</Data></Cell>
<Cell><Data ss:Type="String">SIMPLE</Data></Cell>
<Cell><Data ss:Type="String">984.38</Data></Cell>
<Cell><Data ss:Type="String">922.94</Data></Cell>
<Cell><Data ss:Type="String">61.44</Data></Cell>
<Cell><Data ss:Type="String">19.62</Data></Cell>
<Cell><Data ss:Type="String">37</Data></Cell>
<Cell><Data ss:Type="String">10/02/2012 07:43:26</Data></Cell>
</Row>
<Row ss:StyleID="s63">
<Cell><Data ss:Type="String"></Data></Cell>
</Row>
</Table>
<WorksheetOptions xmlns="urn:schemas-microsoft-com:office:excel">
<ProtectObjects>False</ProtectObjects>
<ProtectScenarios>False</ProtectScenarios>
</WorksheetOptions>
</Worksheet>
</Workbook>';
WITH XMLNAMESPACES (
DEFAULT 'urn:schemas-microsoft-com:office:spreadsheet',
'urn:schemas-microsoft-com:office:spreadsheet' AS ss
)
, C1 AS (
SELECT
DENSE_RANK() OVER(PARTITION BY n1.t ORDER BY n1.t) AS TID,
ROW_NUMBER() OVER(PARTITION BY n1.t ORDER BY n2.d) AS rn,
n2.d.value('text()[1]', 'varchar(128)') AS val
FROM
@x.nodes('Workbook/Worksheet/Table') AS n1(t)
CROSS APPLY
n1.t.nodes('Row/Cell/Data') AS n2(d)
)
, C2 AS (
SELECT
TID,
(rn - 1) / 13 AS RID,
rn % 13 AS CID,
val
FROM
C1
WHERE
rn > 6
AND rn % 13 IN (4, 5, 6)
)
SELECT
TID,
RID,
[4] AS [Hostname],
[5] AS [DBInstanceName],
[6] AS [DatabaseName]
FROM
C2
PIVOT
(
MAX(val)
FOR CID IN ([4], [5], [6])
) AS P;
GO
February 11, 2014 at 12:54 pm
Forgot to mention that you can populate the variable directly from the xml file.
...
DECLARE @x xml;
SET @x = (
SELECT * FROM OPENROWSET(
BULK 'c:\temp\xmlsamplefile.xml',
SINGLE_BLOB) AS x
);
...
February 11, 2014 at 1:12 pm
Dear gods, someone sent you an Excel file as XML? That's simply evil. Excel is bad enough as it is.
I didn't notice a code sample to be able to assist you in determine what went wrong in your code. Accessing the XML is simple enough, it's just using XQuery. What are you trying to do with it?
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
February 12, 2014 at 2:22 am
thanks a lot hunchback!!!
I don't understand a thing from the code, but it works perfectly. 🙂
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply