October 22, 2012 at 5:33 am
[font="Verdana"]I want to select text which is between 1st and 2nd comma on SQL Server 2005
for Ex:
1: SHOP NO 66/67, PATEL HERITAGE, PLOT NO 15/17, SECTOR 7, KHARGHAR, NAVI MUMBAI 410210
my answer should be PATEL HERITAGE
2: NAYASARAK, CUTTACK, DISTRICT CUTTACK, ORISSA-753002
My answer should be CUTTACK
Please help me to get my desired answer...[/font]
October 22, 2012 at 5:44 am
probably the best most recommended way would be using the delimited split function.
there's also a CHARINDEX2 custom function you could use as well.
/*
--Results
val Item
SHOP NO 66/67, PATEL HERITAGE, PLOT NO 15/17, SECTOR 7, KHARGHAR, NAVI MUMBAI 410210 PATEL HERITAGE
NAYASARAK, CUTTACK, DISTRICT CUTTACK, ORISSA-753002 CUTTACK
*/
with MySampleData(val)
AS
(
SELECT ' SHOP NO 66/67, PATEL HERITAGE, PLOT NO 15/17, SECTOR 7, KHARGHAR, NAVI MUMBAI 410210' UNION ALL
SELECT 'NAYASARAK, CUTTACK, DISTRICT CUTTACK, ORISSA-753002'
)
SELECT MySampleData.*,myFn.Item
FROM MySampleData
CROSS APPLY dbo.DelimitedSplit8K(val,',') myFn
WHERE myFn.ItemNumber=2
Lowell
October 22, 2012 at 6:34 am
CREATE FUNCTION dbo.Split
(
@String varchar(8000),
@Delimiter char(1),
@RetStrPos int
)
returns varchar(100)
as
begin
declare @idx int
declare @slice varchar(8000)
declare @temptable table(recno int,items varchar(8000))
declare @recno int =0
declare @retstr varchar(100)
select @idx = 1
if len(@String)<1 or @String is null return @retstr
while @idx!= 0
begin
set @idx = charindex(@Delimiter,@String)
if @idx!=0
set @slice = left(rtrim(ltrim(@String)),@idx - 1)
else
set @slice = rtrim(ltrim(@String))
if(len(@slice)>0)
insert into @temptable(recno,Items) values(@recno,@slice)
set @recno = @recno+1
set @String = right(@String,len(@String) - @idx)
if len(@String) = 0 break
end
select @retStr=items from @temptable where recno=@RetStrPos
return @retstr
end
To get second word,
select dbo.Split('hello,world,how,are,YOU',',',1)
October 22, 2012 at 6:44 am
here's the DelimitedSplit8k function and you can read the article at:
http://www.sqlservercentral.com/articles/Tally+Table/72993/">
http://www.sqlservercentral.com/articles/Tally+Table/72993/
CREATE FUNCTION [dbo].[DelimitedSplit8K]
--===== Define I/O parameters
(@pString VARCHAR(8000), @pDelimiter CHAR(1))
--WARNING!!! DO NOT USE MAX DATA-TYPES HERE! IT WILL KILL PERFORMANCE!
RETURNS TABLE WITH SCHEMABINDING AS
RETURN
--===== "Inline" CTE Driven "Tally Table" produces values from 1 up to 10,000...
-- enough to cover VARCHAR(8000)
WITH E1(N) AS (
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1
), --10E+1 or 10 rows
E2(N) AS (SELECT 1 FROM E1 a, E1 b), --10E+2 or 100 rows
E4(N) AS (SELECT 1 FROM E2 a, E2 b), --10E+4 or 10,000 rows max
cteTally(N) AS (--==== This provides the "base" CTE and limits the number of rows right up front
-- for both a performance gain and prevention of accidental "overruns"
SELECT TOP (ISNULL(DATALENGTH(@pString),0)) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4
),
cteStart(N1) AS (--==== This returns N+1 (starting position of each "element" just once for each delimiter)
SELECT 1 UNION ALL
SELECT t.N+1 FROM cteTally t WHERE SUBSTRING(@pString,t.N,1) = @pDelimiter
),
cteLen(N1,L1) AS(--==== Return start and length (for use in substring)
SELECT s.N1,
ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000)
FROM cteStart s
)
--===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.
SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY l.N1),
Item = SUBSTRING(@pString, l.N1, l.L1)
FROM cteLen l
;
---------------------------------------------------------------
Mike Hahn - MCSomething someday:-)
Right way to ask for help!!
http://www.sqlservercentral.com/articles/Best+Practices/61537/
I post so I can see my avatar :hehe:
I want a personal webpage 😎
I want to win the lotto 😀
I want a gf like Tiffa :w00t: Oh wait I'm married!:-D
October 22, 2012 at 9:22 am
SQLLux (10/22/2012)
CREATE FUNCTION dbo.Split(
@String varchar(8000),
@Delimiter char(1),
@RetStrPos int
)
returns varchar(100)
as
begin
declare @idx int
declare @slice varchar(8000)
declare @temptable table(recno int,items varchar(8000))
declare @recno int =0
declare @retstr varchar(100)
select @idx = 1
if len(@String)<1 or @String is null return @retstr
while @idx!= 0
begin
set @idx = charindex(@Delimiter,@String)
if @idx!=0
set @slice = left(rtrim(ltrim(@String)),@idx - 1)
else
set @slice = rtrim(ltrim(@String))
if(len(@slice)>0)
insert into @temptable(recno,Items) values(@recno,@slice)
set @recno = @recno+1
set @String = right(@String,len(@String) - @idx)
if len(@String) = 0 break
end
select @retStr=items from @temptable where recno=@RetStrPos
return @retstr
end
To get second word,
select dbo.Split('hello,world,how,are,YOU',',',1)
You should read the article suggested in the post after yours. The link posted won't work but the one in my signature about splitting strings does. The split you posted will work but the delimitedSplit8k will blow the doors of a while loop for performance.
_______________________________________________________________
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/
February 13, 2014 at 10:00 am
Thanks for both the functions!! Both of them were extremely useful.
February 13, 2014 at 11:36 am
pruthvi116 (2/13/2014)
Thanks for both the functions!! Both of them were extremely useful.
My recommendation would be to avoid any and all functions, especially split functions, that contain the words "WHILE" or "BEGIN". That would make them either Scalar or Multi-Statement functions that will rob your application of performance and use way more resources than they ever should.
Please see the following article for a demonstration of exactly what I'm talking about.
http://www.sqlservercentral.com/articles/T-SQL/91724/
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply