Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Flatten a one to many?


Flatten a one to many?

Author
Message
kpwimberger
kpwimberger
SSC Rookie
SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)

Group: General Forum Members
Points: 46 Visits: 128
Okay all, just got out of a meeting and went back to it. I think I have it all sorted except for one, tiny portion:

, 'StorageLocation'
         = STUFF
            (
               (
                  SELECT ','
                     + COALESCE('Rm: ' + lbr2.Room, '')
                     + COALESCE(', Cab: ' + ll2.fkCabinet, '')
                     + COALESCE(', Bin: ' + CAST(DecryptByKey(ll2.Bin) AS varchar(20)), '')
                     + COALESCE(', Box: ' + CAST(DecryptByKey(ll2.Box) AS varchar(20)), '')
                     + COALESCE(', ' + CAST(DecryptByKey(ll2.StartColumn) AS varchar(2))
                     + CAST(DecryptByKey(ll2.StartRow) AS varchar(2)), '')
                     + COALESCE(' --> ' + CAST(DecryptByKey(ll2.EndColumn) AS varchar(2))
                     + CAST(DecryptByKey(ll2.EndRow) AS varchar(2)), '')
                  FROM
                     dbo.tblLotLocation AS ll2
                     INNER JOIN
                     dbo.tblLocationBldgRoom AS lbr2 ON lbr2.pkLocationBldgRoomId = ll2.fkLocationBldgRoomId
                  WHERE
                     ll2.fkItemLotId = od.fkItemLotId
                  ORDER BY
                     pkLotLocationId
                  FOR XML PATH(''),
                  TYPE
               Wink.value('.','varchar(max)')
               ,1
               ,1
               ,''
            Wink   


This is the section I am a bit stuck on:
).value('.','varchar(max)')



I have read that .value() is an XQury function that accepts an XML data type and converts it to SQL Server data type. Makes sense.
From MSDN: value (XQuery, SQLType), where "XQuery - is the XQuery expression, a string literal, that retrieves data inside the XML instance" and "SQLType - Is the preferred SQL type."

But what is the XQuery '.' literal actually doing? Can I *assume* that since an empty string is sent to
FOR XML PATH('')

no root node name is created, and that the '.' argument in the XQuery is just looking at the unnamed root for its data?

Thanks.

Kurt
Orlando Colamatteo
Orlando Colamatteo
SSCrazy Eights
SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)

Group: General Forum Members
Points: 8231 Visits: 14368
But what is the XQuery '.' literal actually doing? Can I *assume* that since an empty string is sent to
FOR XML PATH('')

no root node name is created, and that the '.' argument in the XQuery is just looking at the unnamed root for its data?


As a test, change your code to look like this and see if it makes more sense to see that the FOR XML piece of the query is actually returning an XML document.

The .value is actually just picking up the contents of the root level node of that document, i.e. the '.' node, and casting it to a VARCHAR(MAX).


, 'StorageLocation'
         =
               (
                  SELECT ','
                     + COALESCE('Rm: ' + lbr2.Room, '')
                     + COALESCE(', Cab: ' + ll2.fkCabinet, '')
                     + COALESCE(', Bin: ' + CAST(DecryptByKey(ll2.Bin) AS varchar(20)), '')
                     + COALESCE(', Box: ' + CAST(DecryptByKey(ll2.Box) AS varchar(20)), '')
                     + COALESCE(', ' + CAST(DecryptByKey(ll2.StartColumn) AS varchar(2))
                     + CAST(DecryptByKey(ll2.StartRow) AS varchar(2)), '')
                     + COALESCE(' --> ' + CAST(DecryptByKey(ll2.EndColumn) AS varchar(2))
                     + CAST(DecryptByKey(ll2.EndRow) AS varchar(2)), '')
                  FROM
                     dbo.tblLotLocation AS ll2
                     INNER JOIN
                     dbo.tblLocationBldgRoom AS lbr2 ON lbr2.pkLocationBldgRoomId = ll2.fkLocationBldgRoomId
                  WHERE
                     ll2.fkItemLotId = od.fkItemLotId
                  ORDER BY
                     pkLotLocationId
                  FOR XML PATH(''),
                  TYPE
               Wink





edit: add quote

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
kpwimberger
kpwimberger
SSC Rookie
SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)

Group: General Forum Members
Points: 46 Visits: 128
Excellent! That's what I thought. Thanks.

Kurt
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