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


LEFT and RIGHT of Delimiter


LEFT and RIGHT of Delimiter

Author
Message
SQL_Enthusiast
SQL_Enthusiast
Old Hand
Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)

Group: General Forum Members
Points: 388 Visits: 422
I have a value that is '0111~Group Name' in a column called GROUP_NUM in a table called TEMP_TABLE

I need to know how to select everything LEFT of the ~ and then RIGHT of the ~, but not show the TILDE. SELECT LEFT VALUE, RIGHT VALUE FROM TEMP_TABLE...

I tried..., but it failed. Not enough arguements. Thoughts, suggestions, references?

SELECT LTRIM(RTRIM(SUBSTRING([tt].[GROUP_NUM], CHARINDEX('~')))) FROM [dbo].[TEMP_TABLE] AS tt


Sergiy
Sergiy
SSCertifiable
SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)

Group: General Forum Members
Points: 5846 Visits: 11406
SQL_Enthusiast (5/7/2013)
I have a value that is '0111~Group Name' in a column called GROUP_NUM in a table called TEMP_TABLE

I need to know how to select everything LEFT of the ~ and then RIGHT of the ~, but not show the TILDE. SELECT LEFT VALUE, RIGHT VALUE FROM TEMP_TABLE...

I tried..., but it failed. Not enough arguements. Thoughts, suggestions, references?

SELECT LTRIM(RTRIM(SUBSTRING([tt].[GROUP_NUM], CHARINDEX('~')))) FROM [dbo].[TEMP_TABLE] AS tt


You really need to read the Manual. :-)
Which is BOL (Books On Line), which is "Help" (F1).

SUBSTRING takes 3 arguements - String, Position From, Position To.

In your case - SUBSTRING([tt].[GROUP_NUM], 1, CHARINDEX('~'))

For the RIGHT part use REVERSE function:

Reverse the sourse string ([tt].[GROUP_NUM]), do the SUBSTRING thing and then reverse the output.
SQL_Enthusiast
SQL_Enthusiast
Old Hand
Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)

Group: General Forum Members
Points: 388 Visits: 422
I did read BOL, along with 50 other articles that really didn't help. So I figured it out on my own. I'm open to suggestions on how to make it better, but for now... it works so I'm smiling :-D



SELECT
[tt].[GROUP_NUM]
, CASE WHEN [tt].[GROUP_NUM] LIKE '%~%'
THEN SUBSTRING([tt].[GROUP_NUM] , 1 ,
CHARINDEX('~' , [tt].[GROUP_NUM]) - 1)
END AS 'LEFT'
, CASE WHEN [tt].[GROUP_NUM] LIKE '%~%'
THEN (SELECT RIGHT([tt].[GROUP_NUM], CHARINDEX('~', REVERSE([tt].[GROUP_NUM])) -1))
END AS 'RIGHT'
FROM
[dbo].[TEMP_TABLE] AS tt




Sergiy
Sergiy
SSCertifiable
SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)

Group: General Forum Members
Points: 5846 Visits: 11406
SQL_Enthusiast (5/7/2013)
I did read BOL, along with 50 other articles that really didn't help. So I figured it out on my own. I'm open to suggestions on how to make it better, but for now... it works so I'm smiling :-D



SELECT
[tt].[GROUP_NUM]
, CASE WHEN [tt].[GROUP_NUM] LIKE '%~%'
THEN SUBSTRING([tt].[GROUP_NUM] , 1 ,
CHARINDEX('~' , [tt].[GROUP_NUM]) - 1)
END AS 'LEFT'
, CASE WHEN [tt].[GROUP_NUM] LIKE '%~%'
THEN (SELECT RIGHT([tt].[GROUP_NUM], CHARINDEX('~', REVERSE([tt].[GROUP_NUM])) -1))
END AS 'RIGHT'
FROM
[dbo].[TEMP_TABLE] AS tt





I would make it differently, but not sure I could make it much better. :-)

Only note - your CASE statements are missing ELSE parts.
If there is no ~ in the string both LEFT and RIGHT parts will be NULL - is it as intended?
SQL_Enthusiast
SQL_Enthusiast
Old Hand
Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)Old Hand (388 reputation)

Group: General Forum Members
Points: 388 Visits: 422
Yes, no tilde = NULL. That was intended... Thank you
Steven Willis
Steven Willis
SSC-Addicted
SSC-Addicted (483 reputation)SSC-Addicted (483 reputation)SSC-Addicted (483 reputation)SSC-Addicted (483 reputation)SSC-Addicted (483 reputation)SSC-Addicted (483 reputation)SSC-Addicted (483 reputation)SSC-Addicted (483 reputation)

Group: General Forum Members
Points: 483 Visits: 1721


IF OBJECT_ID('tempdb..#TempTable') IS NOT NULL
DROP TABLE #TempTable

CREATE TABLE #TempTable (
[ID] INT IDENTITY(1,1) NOT NULL,
[DString] NVARCHAR(255) NULL,
PRIMARY KEY (ID))

INSERT INTO #TempTable
SELECT '0111~Apple' UNION ALL
SELECT '0222~Banana' UNION ALL
SELECT '0333~Carrot' UNION ALL
SELECT '0444~Danish' UNION ALL
SELECT '0555~Eclair'






SELECT
ID
,DString
,dsk1.Item AS Code
,dsk2.Item AS Item
FROM
#TempTable AS tt
CROSS APPLY
dbo.DelimitedSplit8K(tt.DString,'~') AS dsk1
CROSS APPLY
dbo.DelimitedSplit8K(tt.DString,'~') AS dsk2
WHERE
dsk1.ItemNumber = 1
AND dsk2.ItemNumber = 2




OUTPUT



ID DString Code Item
1 0111~Apple 0111 Apple
2 0222~Banana 0222 Banana
3 0333~Carrot 0333 Carrot
4 0444~Danish 0444 Danish
5 0555~Eclair 0555 Eclair




OR AS XML



<?xml version="1.0" ?>
<RESULTS1>
<RECORD>
<ID>1</ID>
<DString>0111~Apple</DString>
<Code>0111</Code>
<Item>Apple</Item>
</RECORD>
<RECORD>
<ID>2</ID>
<DString>0222~Banana</DString>
<Code>0222</Code>
<Item>Banana</Item>
</RECORD>
<RECORD>
<ID>3</ID>
<DString>0333~Carrot</DString>
<Code>0333</Code>
<Item>Carrot</Item>
</RECORD>
<RECORD>
<ID>4</ID>
<DString>0444~Danish</DString>
<Code>0444</Code>
<Item>Danish</Item>
</RECORD>
<RECORD>
<ID>5</ID>
<DString>0555~Eclair</DString>
<Code>0555</Code>
<Item>Eclair</Item>
</RECORD>
</RESULTS1>



Sergiy
Sergiy
SSCertifiable
SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)

Group: General Forum Members
Points: 5846 Visits: 11406
Steven Willis (5/7/2013)

    AND dsk2.ItemNumber = 2




OP asked for the last (most right) part of the string, not for the second.
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8995 Visits: 19028
Sergiy (5/7/2013)
Steven Willis (5/7/2013)

    AND dsk2.ItemNumber = 2




OP asked for the last (most right) part of the string, not for the second.


OP refers to "the tilde" in numerous places. One delimiter == two elements.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Eugene Elutin
Eugene Elutin
Hall of Fame
Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)Hall of Fame (3K reputation)

Group: General Forum Members
Points: 3042 Visits: 5478
No real need for dbo.DelimitedSplit8K here if you only expect maximum two parts (left and right). The following will work a bit faster (please note extended sample data):


IF OBJECT_ID('tempdb..#TempTable') IS NOT NULL
DROP TABLE #TempTable

CREATE TABLE #TempTable (
[ID] INT IDENTITY(1,1) NOT NULL,
[DString] NVARCHAR(255) NULL,
PRIMARY KEY (ID))

INSERT INTO #TempTable
SELECT '0111~Apple' UNION ALL
SELECT '02222~Banana' UNION ALL
SELECT '033333~Carrot' UNION ALL
SELECT '044444~Danish' UNION ALL
SELECT '0555555~Eclair' UNION ALL
SELECT '000 NO TILDA' UNION ALL
SELECT NULL


SELECT
ID
,DString
,LEFT(DString, tld.ix - 1) AS [LEFT]
,SUBSTRING(DString, tld.ix + 1, 8000) AS [RIGHT]
FROM
#TempTable AS tt
CROSS APPLY (SELECT NULLIF(CHARINDEX('~',tt.DString),0)) tld(ix)



_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
sqldriver
sqldriver
Mr or Mrs. 500
Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)Mr or Mrs. 500 (586 reputation)

Group: General Forum Members
Points: 586 Visits: 2492
I picked up this parsename trick on here and have been loving it for ad hoc queries.


with data(col) as (
SELECT '0222~Banana' UNION ALL
SELECT '0333~Carrot' UNION ALL
SELECT '0444~Danish' UNION ALL
SELECT '0555~Eclair'
)
select parsename(replace(col, '~', '.'), 2) as 'Left',
parsename(replace(col, '~', '.'), 1) as 'Right'
from data
where col like '%~%'


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