t-SQL-XML: Use of “FOR XML EXPLICIT” and same query by using “FOR XML PATH”

“FOR XML EXPLICIT”

Input t-SQL:

declare @agent table
 (
 AgentID int,
 Fname varchar(5),
 SSN varchar(11)
 )

insert into @agent
 select 1, 'Vimal', '123-23-4521' union all
 select 2, 'Jacob', '321-52-4562' union all
 select 3, 'Tom', '252-52-4563'

declare @address table
 (
 AddressID int,
 AddressType varchar(12),
 Address1 varchar(20),
 Address2 varchar(20),
 City varchar(25),
 AgentID int
 )

insert into @address
 select 1, 'Home', 'abc', 'xyz road', 'RJ', 1 union all
 select 2, 'Office', 'temp', 'ppp road', 'RJ', 1 union all
 select 3, 'Home', 'xxx', 'aaa road', 'NY', 2 union all
 select 4, 'Office', 'ccc', 'oli Com', 'CL', 2 union all
 select 5, 'Temp', 'eee', 'olkiu road', 'CL', 2 union all
 select 6, 'Home', 'ttt', 'loik road', 'NY', 3

SELECT
	1 AS Tag,
	NULL AS Parent,
	0 AS 'Agents!1!Sort!hide',
	NULL AS 'Agents!1!',
	NULL AS 'Agent!2!AgentID',
	NULL AS 'Agent!2!Fname!Element',
	NULL AS 'Agent!2!SSN!Element',
	NULL AS 'AddressCollection!3!Element',
	NULL AS 'Address!4!!xml',
	NULL AS 'Address!4!AddressType!Element',
	NULL AS 'Address!4!Address1!Element',
	NULL AS 'Address!4!Address2!Element',
	NULL AS 'Address!4!City!Element'
UNION ALL
	SELECT
	2 AS Tag,
	1 AS Parent,
	AgentID * 100,
	NULL, AgentID, Fname, SSN,
	NULL, NULL, NULL, NULL, NULL, NULL
FROM @Agent
UNION ALL SELECT
	3 AS Tag,
	2 AS Parent,
	AgentID * 100 + 1,
	NULL,NULL,NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL
FROM @Agent
UNION ALL SELECT
	4 AS Tag,
	3 AS Parent,
	AgentID * 100 + 2,
	NULL, NULL, NULL, NULL, NULL,
	'<!-- ' + AddressType + ' Address -->', AddressType,
	Address1, Address2, City
FROM @Address
ORDER BY [Agents!1!Sort!hide]
FOR XML EXPLICIT


“FOR XML PATH”

Input t-SQL:

SELECT 
	ag.AgentID AS "@AgentID",
	ag.Fname AS "Fname",
	ag.SSN AS "SSN",
	(
	SELECT
		AddressType + ' Address' AS "comment()", 
		AddressType,
		Address1,
		Address2,
		City
	FROM @address ad
	WHERE ag.AgentID = ad.AgentID
	FOR XML PATH('Address'), ROOT('AddressCollection'), TYPE 
	)
FROM @Agent ag
FOR XML PATH('Agent'), ROOT('Agents'), TYPE

Output XML:

<Agents>
  <Agent AgentID="1">
    <Fname>Vimal</Fname>
    <SSN>123-23-4521</SSN>
    <AddressCollection>
      <Address>
        <!-- Home Address --> 
        <AddressType>Home</AddressType>
        <Address1>abc</Address1>
        <Address2>xyz road</Address2>
        <City>RJ</City>
      </Address>
      <Address>
        <!-- Office Address -->
        <AddressType>Office</AddressType>
        <Address1>temp</Address1>
        <Address2>ppp road</Address2>
        <City>RJ</City>
      </Address>
    </AddressCollection>
  </Agent>
  <Agent AgentID="2">
    <Fname>Jacob</Fname>
    <SSN>321-52-4562</SSN>
    <AddressCollection>
      <Address>
        <!-- Home Address --> 
        <AddressType>Home</AddressType>
        <Address1>xxx</Address1>
        <Address2>aaa road</Address2>
        <City>NY</City>
      </Address>
      <Address>
        <!-- Office Address -->
        <AddressType>Office</AddressType>
        <Address1>ccc</Address1>
        <Address2>oli Com</Address2>
        <City>CL</City>
      </Address>
      <Address>
        <!-- Temp Address -->
        <AddressType>Temp</AddressType>
        <Address1>eee</Address1>
        <Address2>olkiu road</Address2>
        <City>CL</City>
      </Address>
    </AddressCollection>
  </Agent>
  <Agent AgentID="3">
    <Fname>Tom</Fname>
    <SSN>252-52-4563</SSN>
    <AddressCollection>
      <Address>
        <!-- Home Address --> 
        <AddressType>Home</AddressType>
        <Address1>ttt</Address1>
        <Address2>loik road</Address2>
        <City>NY</City>
      </Address>
    </AddressCollection>
  </Agent>
</Agents>

Reff:

1. http://beyondrelational.com/blogs/jacob/archive/2009/01/07/for-xml-explicit-tutorial-part-4.aspx

2. http://social.msdn.microsoft.com/Forums/en-US/sqlxml/thread/f518b80a-348c-4a0c-a05a-8deda834d136/

Advertisements
By simplemsexchange Posted in SQL 2008

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s