Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Update new columns with data from an xml column

Author  Topic 

peter.mulholland
Starting Member

1 Post

Posted - 2013-06-28 : 03:55:12
I've got an SQL Server 2008 table with an id and a column for xml.
Analysts would like to be able to query the data in the xml, so I've got an alter table script to add the new columns and I believe I can update the sproc to extract the data from the xml for new inserts.

I'm having some trouble figuring out how to construct an update statement for the data already in the table to select the rows and extract the new column data from the xml already in the table.

My original table is something like:
CREATE TABLE [Transactions](
[TxnId] int NOT NULL PRIMARY KEY,
[TxnData] [nvarchar](max) NULL
)

I intend altering the table as follows:
ALTER TABLE [Transactions]
ALTER COLUMN [TxnData] xml
go

ALTER TABLE [Transactions]
ADD AccountName varchar(30),
AccountNumber int,
TxnType varchar(20),
TxnAmount decimal(9,2),
TxnDate datetime
GO

And the xml in the TxnData column is in the form:
<Transaction xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns:xsd="http://www.w3.org/2001/XMLSchema">
<TxnID>112233</RequestCode>
<AccountName>Pete</AccountName>
<AccountNumber>12345678</AccountNumber>
<TxnType>Credit</TxnType>
<TxnAmount>7.21</TxnAmount>
<TxnDate>2013-03-08T00:00:00</TxnDate>
</Transaction>


So how do I do an update pulling the xml from the TxnData column and extracting the data from the xml to populate the other columns?

Thanks,


Pete

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-06-28 : 04:12:18
do like this

UPDATE t
SET AccountName = AcctName,
AccountNumber = AcctNo,
TxnType = TType,
TxnAmount = TAmt,
TxnDate = CONVERT(datetime,TDate,126)
FROM
(
SELECT m.n.value('(./AccountName)[1]','varchar(20)') AS AccntName,
m.n.value('(./AccountNumber)[1]','int') AS AccntNo,
m.n.value('(./AccountName)[1]','varchar(20)') AS AccntName,
m.n.value('(./TxnType)[1]','varchar(20)') AS TType,
m.n.value('(./TxnAmount)[1]','decimal(10,2)') AS TAmt,
m.n.value('(./TxnDate)[1]','varchar(30)') AS TDate,
AccountName,
AccountNumber,
TxnType,
TxnAmount,
TxnDate
FROM [Transactions] tn
CROSS APPLY TxnData.nodes('/Transaction')m(n)
)t


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
   

- Advertisement -