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


XQuery error


XQuery error

Author
Message
Lisa Cherney
Lisa Cherney
SSC-Enthusiastic
SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)

Group: General Forum Members
Points: 172 Visits: 3324
I am trying the following:


declare @packXML XML = '<Pack>
<PackID>1</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>1</Qty>
</Item>
</Pack>
<Pack>
<PackID>2</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>5</Qty>
</Item>
<Item>
<ItemNumber>2</ItemNumber>
<Qty>10</Qty>
</Item>
</Pack>
'

create table #PackItems (PackID int, ItemNumber int, Qty int)

insert into #PackItems(PackID, ItemNumber, Qty)
select N.value('PackID[1]','int'), N.value('(Item/ItemNumber[1])','int'), N.value('(Item/Qty)[1]','int')
from @packXML.nodes('Pack') as T(N)

select * from #PackItems

drop table #PackItems




This gives me this error:
Msg 2389, Level 16, State 1, Line 24
XQuery [value()]: 'value()' requires a singleton (or empty sequence), found operand of type 'xdt:untypedAtomic *'

What am I doing wrong?
Alan Burstein
Alan Burstein
SSC Guru
SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)

Group: General Forum Members
Points: 54140 Visits: 8986
Your first Xpath Expression for Item/ItemNumber is wrong

Instead of
N.value('(Item/ItemNumber[1])','int')

You want
N.value('(Item/ItemNumber)[1]','int')



declare @packXML XML = '<Pack>
<PackID>1</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>1</Qty>
</Item>
</Pack>
<Pack>
<PackID>2</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>5</Qty>
</Item>
<Item>
<ItemNumber>2</ItemNumber>
<Qty>10</Qty>
</Item>
</Pack>
'
select N.value('PackID[1]','int'), N.value('(Item/ItemNumber)[1]','int'), N.value('(Item/Qty)[1]','int')
from @packXML.nodes('Pack') as T(N)



-- Alan Burstein


Helpful links:

Best practices for getting help on SQLServerCentral -- Jeff Moden
How to Post Performance Problems -- Gail Shaw

Nasty fast set-based string manipulation functions:
For splitting strings try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL Server 2012+)
To split strings based on patterns try PatternSplitCM
Need to clean or transform a string? try NGrams, PatExclude8K, PatReplace8K, DigitsOnlyEE, or Translate8K

I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. -- Itzik Ben-Gan 2001

Lisa Cherney
Lisa Cherney
SSC-Enthusiastic
SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)

Group: General Forum Members
Points: 172 Visits: 3324
Alan.B - Monday, April 24, 2017 3:24 PM
Your first Xpath Expression for Item/ItemNumber is wrong

Instead of
N.value('(Item/ItemNumber[1])','int')

You want
N.value('(Item/ItemNumber)[1]','int')



declare @packXML XML = '<Pack>
<PackID>1</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>1</Qty>
</Item>
</Pack>
<Pack>
<PackID>2</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>5</Qty>
</Item>
<Item>
<ItemNumber>2</ItemNumber>
<Qty>10</Qty>
</Item>
</Pack>
'
select N.value('PackID[1]','int'), N.value('(Item/ItemNumber)[1]','int'), N.value('(Item/Qty)[1]','int')
from @packXML.nodes('Pack') as T(N)

Thanks Alan, that resolves the error, but now I realize that it doesn't give me the results I'm looking for.

I really need a row for each Item node, so my expected results should be:
https://www.sqlservercentral.com/Forums/Uploads/Images/3a0b1d27-7de6-4e15-9563-43f6.PNG
Alan Burstein
Alan Burstein
SSC Guru
SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)

Group: General Forum Members
Points: 54140 Visits: 8986
Lisa Cherney - Monday, April 24, 2017 3:37 PM
Alan.B - Monday, April 24, 2017 3:24 PM
Your first Xpath Expression for Item/ItemNumber is wrong

Instead of
N.value('(Item/ItemNumber[1])','int')

You want
N.value('(Item/ItemNumber)[1]','int')



declare @packXML XML = '<Pack>
<PackID>1</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>1</Qty>
</Item>
</Pack>
<Pack>
<PackID>2</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>5</Qty>
</Item>
<Item>
<ItemNumber>2</ItemNumber>
<Qty>10</Qty>
</Item>
</Pack>
'
select N.value('PackID[1]','int'), N.value('(Item/ItemNumber)[1]','int'), N.value('(Item/Qty)[1]','int')
from @packXML.nodes('Pack') as T(N)

Thanks Alan, that resolves the error, but now I realize that it doesn't give me the results I'm looking for.

I really need a row for each Item node, so my expected results should be:
https://www.sqlservercentral.com/Forums/Uploads/Images/3a0b1d27-7de6-4e15-9563-43f6.PNG

This should do the trick:


SELECT
N.value('(../PackID/text())[1]', 'int'),
N.value('(ItemNumber/text())[1]','int'),
N.value('(Qty/text())[1]','int')
FROM @packXML.nodes('Pack/Item') as T(N);


-- Alan Burstein


Helpful links:

Best practices for getting help on SQLServerCentral -- Jeff Moden
How to Post Performance Problems -- Gail Shaw

Nasty fast set-based string manipulation functions:
For splitting strings try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL Server 2012+)
To split strings based on patterns try PatternSplitCM
Need to clean or transform a string? try NGrams, PatExclude8K, PatReplace8K, DigitsOnlyEE, or Translate8K

I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. -- Itzik Ben-Gan 2001

Mikael Eriksson SE
Mikael Eriksson SE
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1572 Visits: 1035
Using the parent axis when extracting values from XML is not good for performance.
Use an extra cross apply instead.

select P.X.value('(PackID/text())[1]','int') as PackID, 
I.X.value('(ItemNumber/text())[1]','int') as ItemNumber,
I.X.value('(Qty/text())[1]','int') as Qty
from @packXML.nodes('/Pack') as P(X)
cross apply P.X.nodes('Item') as I(X);


For more info on the problem with the parent axis you can have a look at this question on StackOverflow:
Cross apply xml query performs exponentially worse as xml document grows
.






Lisa Cherney
Lisa Cherney
SSC-Enthusiastic
SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)

Group: General Forum Members
Points: 172 Visits: 3324
Thanks Alan and Mikael for helping solve my issue, and for the info on performance issues.
Alan Burstein
Alan Burstein
SSC Guru
SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)

Group: General Forum Members
Points: 54140 Visits: 8986
Mikael Eriksson SE - Monday, April 24, 2017 11:34 PM
Using the parent axis when extracting values from XML is not good for performance.
Use an extra cross apply instead.

select P.X.value('(PackID/text())[1]','int') as PackID, 
I.X.value('(ItemNumber/text())[1]','int') as ItemNumber,
I.X.value('(Qty/text())[1]','int') as Qty
from @packXML.nodes('/Pack') as P(X)
cross apply P.X.nodes('Item') as I(X);


For more info on the problem with the parent axis you can have a look at this question on StackOverflow:
Cross apply xml query performs exponentially worse as xml document grows
.



Well done Mikael. I would have thought that the extra APPLY would increase the overhead but you are 100% right - the parent axis is a killer. I looked at the link you posted which includes some good info but also did a quick performance test and was blown away at the difference.


IF OBJECT_ID('tempdb..#tmp') IS NOT NULL DROP TABLE #tmp;
CREATE TABLE #tmp (packkey int identity primary key, packXML XML NOT NULL);

INSERT #tmp(packXML)
SELECT TOP (100000)
'<Pack>
<PackID>'+ CAST(abs(checksum(newid())%10) AS varchar(2)) +'</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>'+ CAST(abs(checksum(newid())%20)+1 AS varchar(2)) +'</Qty>
</Item>
</Pack>
<Pack>
<PackID>2</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>'+ CAST(abs(checksum(newid())%20)+1 AS varchar(2)) +'</Qty>
</Item>
<Item>
<ItemNumber>2</ItemNumber>
<Qty>'+ CAST(abs(checksum(newid())%90)+1 AS varchar(2)) +'</Qty>
</Item>
</Pack>'
FROM sys.all_columns a, sys.all_columns b;

SET NOCOUNT ON;
IF OBJECT_ID('tempdb..#dump1') IS NOT NULL DROP TABLE #dump1;
IF OBJECT_ID('tempdb..#dump2') IS NOT NULL DROP TABLE #dump2;
GO

SET STATISTICS IO ON;
SET STATISTICS TIME ON;
SELECT
packkey,
N.value('(../PackID/text())[1]', 'int') as PackID,
N.value('(ItemNumber/text())[1]','int') as ItemNumber,
N.value('(Qty/text())[1]','int') as Qty
INTO #dump1
FROM #tmp
CROSS APPLY packXML.nodes('Pack/Item') as T(N);

SELECT
packkey,
P.X.value('(PackID/text())[1]','int') as PackID,
I.X.value('(ItemNumber/text())[1]','int') as ItemNumber,
I.X.value('(Qty/text())[1]','int') as Qty
INTO #dump2
FROM #tmp
CROSS APPLY packXML.nodes('/Pack') as P(X)
CROSS APPLY P.X.nodes('Item') as I(X);
SET STATISTICS TIME OFF;
SET STATISTICS IO OFF;
GO

DROP TABLE #dump1;
DROP TABLE #dump2;
DROP TABLE #tmp;


Results

Table 'Workfile'. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table '#tmp_0000000002B3'. Scan count 3, logical reads 2278, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

SQL Server Execution Times:
CPU time = 25422 ms, elapsed time = 13259 ms.
Table '#tmp_0000000002B3'. Scan count 3, logical reads 2278, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

SQL Server Execution Times:
CPU time = 6313 ms, elapsed time = 3205 ms.

I learned something new today before 9AM.


-- Alan Burstein


Helpful links:

Best practices for getting help on SQLServerCentral -- Jeff Moden
How to Post Performance Problems -- Gail Shaw

Nasty fast set-based string manipulation functions:
For splitting strings try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL Server 2012+)
To split strings based on patterns try PatternSplitCM
Need to clean or transform a string? try NGrams, PatExclude8K, PatReplace8K, DigitsOnlyEE, or Translate8K

I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. -- Itzik Ben-Gan 2001

Lisa Cherney
Lisa Cherney
SSC-Enthusiastic
SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)SSC-Enthusiastic (172 reputation)

Group: General Forum Members
Points: 172 Visits: 3324
Alan.B - Tuesday, April 25, 2017 8:07 AM
Mikael Eriksson SE - Monday, April 24, 2017 11:34 PM
Using the parent axis when extracting values from XML is not good for performance.
Use an extra cross apply instead.

select P.X.value('(PackID/text())[1]','int') as PackID, 
I.X.value('(ItemNumber/text())[1]','int') as ItemNumber,
I.X.value('(Qty/text())[1]','int') as Qty
from @packXML.nodes('/Pack') as P(X)
cross apply P.X.nodes('Item') as I(X);


For more info on the problem with the parent axis you can have a look at this question on StackOverflow:
Cross apply xml query performs exponentially worse as xml document grows
.



Well done Mikael. I would have thought that the extra APPLY would increase the overhead but you are 100% right - the parent axis is a killer. I looked at the link you posted which includes some good info but also did a quick performance test and was blown away at the difference.


IF OBJECT_ID('tempdb..#tmp') IS NOT NULL DROP TABLE #tmp;
CREATE TABLE #tmp (packkey int identity primary key, packXML XML NOT NULL);

INSERT #tmp(packXML)
SELECT TOP (100000)
'<Pack>
<PackID>'+ CAST(abs(checksum(newid())%10) AS varchar(2)) +'</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>'+ CAST(abs(checksum(newid())%20)+1 AS varchar(2)) +'</Qty>
</Item>
</Pack>
<Pack>
<PackID>2</PackID>
<Item>
<ItemNumber>1</ItemNumber>
<Qty>'+ CAST(abs(checksum(newid())%20)+1 AS varchar(2)) +'</Qty>
</Item>
<Item>
<ItemNumber>2</ItemNumber>
<Qty>'+ CAST(abs(checksum(newid())%90)+1 AS varchar(2)) +'</Qty>
</Item>
</Pack>'
FROM sys.all_columns a, sys.all_columns b;

SET NOCOUNT ON;
IF OBJECT_ID('tempdb..#dump1') IS NOT NULL DROP TABLE #dump1;
IF OBJECT_ID('tempdb..#dump2') IS NOT NULL DROP TABLE #dump2;
GO

SET STATISTICS IO ON;
SET STATISTICS TIME ON;
SELECT
packkey,
N.value('(../PackID/text())[1]', 'int') as PackID,
N.value('(ItemNumber/text())[1]','int') as ItemNumber,
N.value('(Qty/text())[1]','int') as Qty
INTO #dump1
FROM #tmp
CROSS APPLY packXML.nodes('Pack/Item') as T(N);

SELECT
packkey,
P.X.value('(PackID/text())[1]','int') as PackID,
I.X.value('(ItemNumber/text())[1]','int') as ItemNumber,
I.X.value('(Qty/text())[1]','int') as Qty
INTO #dump2
FROM #tmp
CROSS APPLY packXML.nodes('/Pack') as P(X)
CROSS APPLY P.X.nodes('Item') as I(X);
SET STATISTICS TIME OFF;
SET STATISTICS IO OFF;
GO

DROP TABLE #dump1;
DROP TABLE #dump2;
DROP TABLE #tmp;


Results

Table 'Workfile'. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table '#tmp_0000000002B3'. Scan count 3, logical reads 2278, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

SQL Server Execution Times:
CPU time = 25422 ms, elapsed time = 13259 ms.
Table '#tmp_0000000002B3'. Scan count 3, logical reads 2278, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

SQL Server Execution Times:
CPU time = 6313 ms, elapsed time = 3205 ms.

I learned something new today before 9AM.
Wow Alan. Thanks for the effort to show the performance differences.

I'll definitely go with Mikael's solution.
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