Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Trying to select XML data for one tag from an text field and isn't returning the data I need Expand / Collapse
Author
Message
Posted Monday, February 11, 2013 5:25 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Sunday, July 20, 2014 7:29 AM
Points: 173, Visits: 340
Hello DBA's/Developers,

I'm trying to select XML data from one tag that is stored in an TEXT data type and can't seem to return the data I need.

e.g. XMLProfile_TXT field and tag </DID>.

When I try to use the following TSQL syntax below, I get '0' for every record returned:

select charindex ('</DID>', XMLProfile_TXT) from table_name

Everytime I select all the XML data I can see the data I need in the result set, but I don't want every tag, I just need the one noted above (e.g. </DID>).

Can someone help? I'm sure this is an easy answer. :)

Thanks!

-Dave



Post #1418692
Posted Tuesday, February 12, 2013 5:00 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 2:26 PM
Points: 2,422, Visits: 7,437
davidsalazar01 (2/11/2013)
Hello DBA's/Developers,

I'm trying to select XML data from one tag that is stored in an TEXT data type and can't seem to return the data I need.

e.g. XMLProfile_TXT field and tag </DID>.

When I try to use the following TSQL syntax below, I get '0' for every record returned:

select charindex ('</DID>', XMLProfile_TXT) from table_name

Everytime I select all the XML data I can see the data I need in the result set, but I don't want every tag, I just need the one noted above (e.g. </DID>).

Can someone help? I'm sure this is an easy answer. :)

Thanks!

-Dave


Hello and welcome to SSC,

If you could knock up some sample data and DDL scripts, then your expected results based on the sample data provided that would be extremely useful in allowing people to help you.

Have a read through this link --> http://www.sqlservercentral.com/articles/Best+Practices/61537/, if you're unsure how best to lay this information out. Remember that if your sample data and DDL script is readily consumable, then the volunteers for this forum are much more likely to take time out from their work to give you a hand.

Thanks.


--EDIT--
This thread (http://www.sqlservercentral.com/Forums/Topic1415340-338-1.aspx) might help.



Not a DBA, just trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


LinkedIn | Blog coming soon (for sufficiently large values of "soon" )!
Post #1418883
Posted Tuesday, February 12, 2013 5:33 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 1:44 PM
Points: 12,880, Visits: 31,799
david the select statement you posted will find where the END tag begins...wouldn't you want the value between the <did> </did> tags?

could the opening <did tag have attributes?

is there more than one <did tag in the xml?

this is how i would do it, using the function DelimitedSplit8K(search SSC for the article)

With table_name (ID,XMLProfile_TXT)
AS
(SELECT 1,'
<div class="MainMenu"
><ul>
<li><did>Home</did></li>
<li><did>Tags</did></li>
<li><did>Articles</did></li>
<li><did>Editorials</did></li>
<li><>Stairways</did></li>
<li><did>Forums</did></li>
<li><did>Scripts</did></li>
<li><did>Videos</did></li>
<li><did>Blogs</did></li>
<li><did>QotD</did></li>
<li><did class="track-clicks MenuItem " href="/Books/" data-event-category="MainMenu: Books">Books</did></li>
<li><did class="track-clicks MenuItem " href="http://ask.sqlservercentral.com" data-event-category="MainMenu: Ask SSC">Ask SSC</did></li>
<li><did class="track-clicks MenuItem " href="http://jobs.sqlservercentral.com/" data-event-category="MainMenu: SQL Jobs">SQL Jobs</did></li>
<li><did class="track-clicks MenuItem " href="/Training/" data-event-category="MainMenu: Training">Training</did></li>
<li><did class="track-clicks MenuItem " href="/Authors/Articles/" data-event-category="MainMenu: Authors">Authors</did></li>
<li><did class="track-clicks MenuItem Minor" href="ssc_showPostsSinceLastVisit()" data-event-category="MainMenu: Active Threads">Active Threads</did></li>
<li><did class="track-clicks MenuItem Minor" href="/About/AboutUs/" data-event-category="MainMenu: About us">About us</did></li>
<li><did class="track-clicks MenuItem Minor" href="/About/ContactUs/" data-event-category="MainMenu: Contact us">Contact us</did></li>
<li><did class="track-clicks MenuItem Minor" href="/NewsletterArchive" data-event-category="MainMenu: Newsletters">Newsletters</did></li>
<li><did class="track-clicks MenuItem Minor" href="/Contributions/Home" data-event-category="MainMenu: Write for us">Write for us</did></li>
</ul>
</div>' UNION ALL
SELECT 2, '<li><did>Home</did></li>
<li><did>Tags</did></li>
<li><did>Articles</did></li>
<li><did>Editorials</did></li>
<li><>Stairways</did></li>
<li><did>Forums</did></li>
<li><did>Scripts</did></li>
<li><did>Videos</did></li>
<li><did>Blogs</did></li>
<li><did>QotD</did></li>
<li><did class="track-c'



)
select
myfn.*,
table_name.*,
REPLACE(myfn.Item,'</did','')
from table_name
CROSS APPLY dbo.DelimitedSplit8K(XMLProfile_TXT,'>') myfn
Where myfn.Item LIKE '%</did'



Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1418896
Posted Tuesday, February 12, 2013 5:58 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Sunday, July 20, 2014 7:29 AM
Points: 173, Visits: 340
Lowell,

It's only one occurence (e.g.<DID>) in the XML and your right I only want the data between the tags. Would the samples you posted do the trick? I appreciate your help!

Thanks,

David



Post #1418908
Posted Tuesday, February 12, 2013 6:03 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 1:44 PM
Points: 12,880, Visits: 31,799
davidsalazar01 (2/12/2013)
Lowell,

It's only one occurence (e.g.<DID>) in the XML and your right I only want the data between the tags. Would the samples you posted do the trick? I appreciate your help!

Thanks,

David


yes it would do it, and is prepared for the other things i mentioned as well: multiple DID tags, and attributes in the opening <did tag as well.

grab the function from this article, and read the article so you can understand what it does; it's a very powerful tool to put in your toolkit.

Tally OH! An Improved SQL 8K “CSV Splitter” Function


Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1418910
Posted Tuesday, February 12, 2013 7:15 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 2:26 PM
Points: 2,422, Visits: 7,437
From the sample data provided by Lowell: -
-- SAMPLE DATA
IF object_id('tempdb..#yourTable') IS NOT NULL
BEGIN
DROP TABLE #yourTable;
END;
SELECT id, CAST(XMLProfile_TXT AS XML) AS XMLProfile_TXT
INTO #yourTable
FROM (VALUES(1, '<div class="MainMenu"><ul><li><did>Home</did></li><li><did>Tags</did></li><li><did>Articles</did></li><li><did>Editorials</did></li><li><did>Stairways</did></li>
<li><did>Forums</did></li><li><did>Scripts</did></li><li><did>Videos</did></li><li><did>Blogs</did></li><li><did>QotD</did></li>
<li><did class="track-clicks MenuItem " href="/Books/" data-event-category="MainMenu: Books">Books</did></li>
<li><did class="track-clicks MenuItem " href="http://ask.sqlservercentral.com" data-event-category="MainMenu: Ask SSC">Ask SSC</did></li>
<li><did class="track-clicks MenuItem " href="http://jobs.sqlservercentral.com/" data-event-category="MainMenu: SQL Jobs">SQL Jobs</did></li>
<li><did class="track-clicks MenuItem " href="/Training/" data-event-category="MainMenu: Training">Training</did></li>
<li><did class="track-clicks MenuItem " href="/Authors/Articles/" data-event-category="MainMenu: Authors">Authors</did></li>
<li><did class="track-clicks MenuItem Minor" href="ssc_showPostsSinceLastVisit()" data-event-category="MainMenu: Active Threads">Active Threads</did></li>
<li><did class="track-clicks MenuItem Minor" href="/About/AboutUs/" data-event-category="MainMenu: About us">About us</did></li>
<li><did class="track-clicks MenuItem Minor" href="/About/ContactUs/" data-event-category="MainMenu: Contact us">Contact us</did></li>
<li><did class="track-clicks MenuItem Minor" href="/NewsletterArchive" data-event-category="MainMenu: Newsletters">Newsletters</did></li>
<li><did class="track-clicks MenuItem Minor" href="/Contributions/Home" data-event-category="MainMenu: Write for us">Write for us</did></li></ul></div>')
)a(id, XMLProfile_TXT);

This is how I'd do it using XML.
SELECT id, ParamValues.XMLProfile_TXT.value('.','VARCHAR(MAX)') AS did
FROM #yourTable
OUTER APPLY XMLProfile_TXT.nodes('/div/ul/li/did') ParamValues(XMLProfile_TXT);

Returns: -
id          did
----------- ---------------
1 Home
1 Tags
1 Articles
1 Editorials
1 Stairways
1 Forums
1 Scripts
1 Videos
1 Blogs
1 QotD
1 Books
1 Ask SSC
1 SQL Jobs
1 Training
1 Authors
1 Active Threads
1 About us
1 Contact us
1 Newsletters
1 Write for us



Not a DBA, just trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


LinkedIn | Blog coming soon (for sufficiently large values of "soon" )!
Post #1418952
Posted Tuesday, February 12, 2013 11:01 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Sunday, July 20, 2014 7:29 AM
Points: 173, Visits: 340
Cadavre,

I'm getting the following error when executing the following SQL:

SELECT ParamValues.XMLProfile_TXT.value('.','VARCHAR(MAX)') AS DID
FROM Payment_Method_T (nolock)
OUTER APPLY XMLProfile_TXT.nodes('/div/ul/li/did') ParamValues(XMLProfile_TXT);

Msg 9506, Level 16, State 1, Line 1
The XMLDT method 'nodes' can only be invoked on columns of type xml.

Can you let me know what I'm doing wrong? Also, is this whole string required (e.g. '/div/ul/li/did')? I only want /DID tag only. What is the other chars for?

Thanks,
David



Post #1419117
Posted Wednesday, February 13, 2013 1:35 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 2:26 PM
Points: 2,422, Visits: 7,437
davidsalazar01 (2/12/2013)
I'm getting the following error when executing the following SQL:

SELECT ParamValues.XMLProfile_TXT.value('.','VARCHAR(MAX)') AS DID
FROM Payment_Method_T (nolock)
OUTER APPLY XMLProfile_TXT.nodes('/div/ul/li/did') ParamValues(XMLProfile_TXT);

Msg 9506, Level 16, State 1, Line 1
The XMLDT method 'nodes' can only be invoked on columns of type xml.

Can you let me know what I'm doing wrong?


I'm going to take a wild guess and say that you aren't storing it as XML, which is why I asked for DDL scripts in my first post: -
Cadavre (2/12/2013)
If you could knock up some sample data and DDL scripts, then your expected results based on the sample data provided that would be extremely useful in allowing people to help you.

Have a read through this link --> http://www.sqlservercentral.com/articles/Best+Practices/61537/, if you're unsure how best to lay this information out. Remember that if your sample data and DDL script is readily consumable, then the volunteers for this forum are much more likely to take time out from their work to give you a hand.


With that in mind, you could cast it to XML, but since I can no longer be certain that your stored data is correct XML syntax it may throw up errors so will probably be easier to use the splitter as suggested by Lowell.

davidsalazar01 (2/12/2013)
Also, is this whole string required (e.g. '/div/ul/li/did')? I only want /DID tag only. What is the other chars for?


Those other characters are required to show where the "did" tag is in relation to the XML schema. I based that on the sample data provided by Lowell because you didn't provide anything for me to work with.



Not a DBA, just trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


LinkedIn | Blog coming soon (for sufficiently large values of "soon" )!
Post #1419333
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse