x

How to avoid duplicate values in xquery outer apply

DECLARE @x XML
SET @x ='<abc id="abc1">
<def id="def1">
<ghi att="ghi1">
  <mn id="0742d2ea" name="RF"  dt="27" df="31" ty="35" />
  <mn id="64d9a11b" name="CJ"  dt="28" df="32" ty="36" />
  <mn id="db72d154" name="FJ"  dt="29" df="33" ty="37" />
  <mn id="39af9fa1" name="BS"  dt="30" df="34" ty="38" />
</ghi>
<jkl  att="jkl1">
   <mn id="0742d2ea" name="RF" dt="11" gl="19" />
   <mn id="64d9a11b" name="CJ" dt="12" gl="20" />
   <mn id="db72d154" name="FJ" dt="13" gl="21" />
   <mn id="39af9fa1" name="BS" dt="14" gl="22" />
   <mn id="ac4f566f" name="DJ" dt="15" gl="23" />
   <mn id="4bf3ba2f" name="RP" dt="16" gl="24" />
   <mn id="db1af021" name="SC" dt="17" gl="25" />
   <mn id="c4c93a2d" name="DN" dt="18" gl="26" />
</jkl>
</def>
</abc>'
SELECT
Z.value('@id[1]','VARCHAR(64)') AS ID,

Z.value('../../@id[1]','VARCHAR(64)') AS Tm,

Z.value('@name[1]','VARCHAR(64)') AS Pl,

Z.value('@dt[1]','int') AS defDT,

Z.value('@gl[1]','int') AS defGL,

coalesce(Y.value('@dt[1]','int'),0) AS abcDT,

coalesce(Y.value('@df[1]','int'), 0) AS abcDF,

coalesce(Y.value('@ty[1]','int'), 0) AS abcTY

FROM @x.nodes('//abc/def/jkl/mn') n(Z) 

outer apply n.Z.nodes('//abc/def/ghi/mn') as c(Y)

where n.Z.value('@id', 'varchar(64)') IN('0742d2ea', '4bf3ba2f', 'c4c93a2d') AND
c.Y.value('@id', 'varchar(64)') IN('0742d2ea', '4bf3ba2f', 'c4c93a2d')

![alt text][1]

[1]: http://ask.sqlservercentral.com/storage/temp/170-Untitled-2.gif
Untitled-2.gif (5.2 kB)
more ▼

asked Apr 15 '12 at 09:09 AM in Default

sirib4u gravatar image

sirib4u
0 1 1 1

It might be helpful if you indicated the answer you were expecting, or wanting...
Apr 15 '12 at 09:18 PM ThomasRushton ♦
(comments are locked)
10|1200 characters needed characters left

1 answer: sort voted first

You are seeing the duplicate value because you are making CROSS JOIN through your query. This could be easily identified if you would add <mn id="39af9fa1" name="BS" dt="30" df="34" ty="38" /> under the <ghi att="ghi1"> tag. Your result would would increase from 3*1=3 rows to 3*2=6 rows.

For the solution, you need to specify the joining keys and tweak your code to something like

SELECT  Z.value('../../@id[1]', 'VARCHAR(64)') AS ID
,       Z.value('@id[1]', 'VARCHAR(64)') AS Tm
,       Z.value('@name[1]', 'VARCHAR(64)') AS Pl
,       Z.value('@dt[1]', 'int') AS defDT
,       Z.value('@gl[1]', 'int') AS defGL
,       COALESCE(X.value('@dt[1]', 'int'), 0) AS abcDT
,       COALESCE(X.value('@df[1]', 'int'), 0) AS abcDF
,       COALESCE(X.value('@ty[1]', 'int'), 0) AS abcTY
FROM    @x.nodes('//abc/def/jkl/mn') n ( Z )
        LEFT JOIN @x.nodes('//abc/def/ghi/mn') AS d ( X )
        ON d.X.value('@id', 'VARCHAR(64)') = n.Z.value('@id', 'VARCHAR(64)')
           AND d.X.value('@id', 'varchar(64)') IN ( '0742d2ea', '4bf3ba2f',
                                                    'c4c93a2d' )
WHERE   n.Z.value('@id', 'varchar(64)') IN ( '0742d2ea', '4bf3ba2f',
                                             'c4c93a2d' ) 
Hope it helps.
more ▼

answered Apr 16 '12 at 06:23 AM

Usman Butt gravatar image

Usman Butt
13.9k 6 8 14

(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

New code box

There's a new way to format code on the site - the red speech bubble logo will automatically format T-SQL for you. The original code box is still there for XML, etc. More details here.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here

By RSS:

Answers

Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.

Topics:

x1816

asked: Apr 15 '12 at 09:09 AM

Seen: 583 times

Last Updated: Apr 16 '12 at 06:23 AM