finding value in a string

  • I have a text value in a string which I can convert to varchar(1000). field I am going to convert look like this.

    I need to extract the values between <EntryID> and </EntryID>

    I was thinking charindex but am stuck

    <NewOrder><InstID>ED</InstID><PatientID>22164</PatientID><LName>fACKSON</LName><FName>JAMES</FName><EntryID>1923236</EntryID><OrderID></NewOrder>

  • timscronin (9/17/2013)


    I have a text value in a string which I can convert to varchar(1000). field I am going to convert look like this.

    I need to extract the values between <EntryID> and </EntryID>

    I was thinking charindex but am stuck

    <NewOrder><InstID>ED</InstID><PatientID>22164</PatientID><LName>fACKSON</LName><FName>JAMES</FName><EntryID>1923236</EntryID><OrderID></NewOrder>

    Your "string" looks to almost be xml???

    As a string you could do this.

    declare @MyValue varchar(1000) = '<NewOrder><InstID>ED</InstID><PatientID>22164</PatientID><LName>fACKSON</LName><FName>JAMES</FName><EntryID>1923236</EntryID><OrderID></NewOrder>'

    select left(SUBSTRING(@MyValue, charindex('<EntryID>', @MyValue) + 9, LEN(@MyValue)), CHARINDEX('</EntryID>', SUBSTRING(@MyValue, charindex('<EntryID>', @MyValue) + 10, LEN(@MyValue))))

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Or this:

    SELECT SUBSTRING(@MyValue, CHARINDEX('<EntryID>', @MyValue) + 9, CHARINDEX('</EntryID>', @MyValue) - CHARINDEX('<EntryID>', @MyValue) - 9)

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • If not for the un-closed <OrderID> tag you would have a well-formed fragment that you could query via XPath. What Scott and Sean included will be better for your requirement. I am just showing another method.

    How you could do it with a well-formed xml fragment

    (note: I changed <OrderID> to <OrderID/>)

    DECLARE @MyValue varchar(1000)=

    '<NewOrder><InstID>ED</InstID><PatientID>22164</PatientID><LName>fACKSON</LName><FName>JAMES</FName><EntryID>1923236</EntryID><OrderID/></NewOrder>'

    SELECT x.value('(/NewOrder/EntryID/text())[1]', 'varchar(100)')

    FROM (VALUES (CAST(@MyValue AS xml))) doc(x)

    With that <OrderID> tag in there you could do this:

    SELECT CAST(REPLACE(@MyValue2,'<OrderID>','<OrderID/>') AS xml).value('(/NewOrder/EntryID/text())[1]', 'varchar(100)')

    "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

  • Yet another way using Jeff Moden's venerated delimited string splitter: DelimitedSplit8K[/url] (download at the link provided):

    declare @MyValue varchar(1000) = '<NewOrder><InstID>ED</InstID><PatientID>22164</PatientID><LName>fACKSON</LName><FName>JAMES</FName><EntryID>1923236</EntryID><OrderID></NewOrder>'

    SELECT LEFT(Item, PATINDEX('%[^0-9]%', Item)-1)

    FROM (SELECT REPLACE(@MyValue, 'EntryID>', CHAR(5))) a(MyStr)

    CROSS APPLY dbo.DelimitedSplit8K(MyStr, CHAR(5))

    WHERE ItemNumber = 2;


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply