July 6, 2012 at 10:09 am
here i am having a table @temptable which is having two column
declare @temptable2 table (firstlevel varchar(200),ThirdLevel varchar(8000) )
insert into @temptable2 (firstlevel,ThirdLevel )
VALUES ('count1','serv,dan,ton'), ('count2','wers,tdan,tondrer,fhhgj,tern')
select * from @temptable2
firstlevelThirdLevel
count1serv,dan,ton
count2wers,tdan,tondrer,fhhgj,tern
in this output the thirdlevel column has comma seprated value this has to be splitted like this
firstlevelThirdLevel
count1serv
count1dan
count1ton
count2wers
count2tdan
count2tondrer
count2fhhgj
count2tern
i wrote a function to split this
-----select * from [dbo].[Split]('ser,sae',',')
create FUNCTION [dbo].[Split](
@delimited NVARCHAR(MAX),
@delimiter NVARCHAR(100)
) RETURNS @t TABLE (id INT IDENTITY(1,1), val NVARCHAR(MAX))
AS
BEGIN
DECLARE @xml XML
SET @xml = N'<t>' + REPLACE(@delimited,@delimiter,'</t><t>') + '</t>'
INSERT INTO @t(val)
SELECT r.value('.','varchar(MAX)') as item
FROM @xml.nodes('/t') as records(r)
RETURN
END
can can one plz tell me how to implement a function to split column
July 6, 2012 at 10:19 am
Like this, code includes a new delimited split function for you.
USE [SandBox]
GO
/****** Object: UserDefinedFunction [dbo].[DelimitedSplit8K] Script Date: 07/06/2012 10:14:55 ******/
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[DelimitedSplit8K]') AND type in (N'FN', N'IF', N'TF', N'FS', N'FT'))
DROP FUNCTION [dbo].[DelimitedSplit8K]
GO
USE [SandBox]
GO
/****** Object: UserDefinedFunction [dbo].[DelimitedSplit8K] Script Date: 07/06/2012 10:14:55 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION [dbo].[DelimitedSplit8K]
/**********************************************************************************************************************
Purpose:
Split a given string at a given delimiter and return a list of the split elements (items).
Notes:
1. Leading a trailing delimiters are treated as if an empty string element were present.
2. Consecutive delimiters are treated as if an empty string element were present between them.
3. Except when spaces are used as a delimiter, all spaces present in each element are preserved.
Returns:
iTVF containing the following:
ItemNumber = Element position of Item as a BIGINT (not converted to INT to eliminate a CAST)
Item = Element value as a VARCHAR(8000)
Statistics on this function may be found at the following URL:
http://www.sqlservercentral.com/Forums/Topic1101315-203-4.aspx
CROSS APPLY Usage Examples and Tests:
--=====================================================================================================================
-- TEST 1:
-- This tests for various possible conditions in a string using a comma as the delimiter. The expected results are
-- laid out in the comments
--=====================================================================================================================
--===== Conditionally drop the test tables to make reruns easier for testing.
-- (this is NOT a part of the solution)
IF OBJECT_ID('tempdb..#JBMTest') IS NOT NULL DROP TABLE #JBMTest
;
--===== Create and populate a test table on the fly (this is NOT a part of the solution).
-- In the following comments, "b" is a blank and "E" is an element in the left to right order.
-- Double Quotes are used to encapsulate the output of "Item" so that you can see that all blanks
-- are preserved no matter where they may appear.
SELECT *
INTO #JBMTest
FROM ( --# & type of Return Row(s)
SELECT 0, NULL UNION ALL --1 NULL
SELECT 1, SPACE(0) UNION ALL --1 b (Empty String)
SELECT 2, SPACE(1) UNION ALL --1 b (1 space)
SELECT 3, SPACE(5) UNION ALL --1 b (5 spaces)
SELECT 4, ',' UNION ALL --2 b b (both are empty strings)
SELECT 5, '55555' UNION ALL --1 E
SELECT 6, ',55555' UNION ALL --2 b E
SELECT 7, ',55555,' UNION ALL --3 b E b
SELECT 8, '55555,' UNION ALL --2 b B
SELECT 9, '55555,1' UNION ALL --2 E E
SELECT 10, '1,55555' UNION ALL --2 E E
SELECT 11, '55555,4444,333,22,1' UNION ALL --5 E E E E E
SELECT 12, '55555,4444,,333,22,1' UNION ALL --6 E E b E E E
SELECT 13, ',55555,4444,,333,22,1,' UNION ALL --8 b E E b E E E b
SELECT 14, ',55555,4444,,,333,22,1,' UNION ALL --9 b E E b b E E E b
SELECT 15, ' 4444,55555 ' UNION ALL --2 E (w/Leading Space) E (w/Trailing Space)
SELECT 16, 'This,is,a,test.' --E E E E
) d (SomeID, SomeValue)
;
--===== Split the CSV column for the whole table using CROSS APPLY (this is the solution)
SELECT test.SomeID, test.SomeValue, split.ItemNumber, Item = QUOTENAME(split.Item,'"')
FROM #JBMTest test
CROSS APPLY dbo.DelimitedSplit8K(test.SomeValue,',') split
;
--=====================================================================================================================
-- TEST 2:
-- This tests for various "alpha" splits and COLLATION using all ASCII characters from 0 to 255 as a delimiter against
-- a given string. Note that not all of the delimiters will be visible and some will show up as tiny squares because
-- they are "control" characters. More specifically, this test will show you what happens to various non-accented
-- letters for your given collation depending on the delimiter you chose.
--=====================================================================================================================
WITH
cteBuildAllCharacters (String,Delimiter) AS
(
SELECT TOP 256
'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789',
CHAR(ROW_NUMBER() OVER (ORDER BY (SELECT NULL))-1)
FROM master.sys.all_columns
)
SELECT ASCII_Value = ASCII(c.Delimiter), c.Delimiter, split.ItemNumber, Item = QUOTENAME(split.Item,'"')
FROM cteBuildAllCharacters c
CROSS APPLY dbo.DelimitedSplit8K(c.String,c.Delimiter) split
ORDER BY ASCII_Value, split.ItemNumber
;
-----------------------------------------------------------------------------------------------------------------------
Other Notes:
1. Optimized for VARCHAR(8000) or less. No testing or error reporting for truncation at 8000 characters is done.
2. Optimized for single character delimiter. Multi-character delimiters should be resolvedexternally from this
function.
3. Optimized for use with CROSS APPLY.
4. Does not "trim" elements just in case leading or trailing blanks are intended.
5. If you don't know how a Tally table can be used to replace loops, please see the following...
http://www.sqlservercentral.com/articles/T-SQL/62867/
6. Changing this function to use NVARCHAR(MAX) will cause it to run twice as slow. It's just the nature of
VARCHAR(MAX) whether it fits in-row or not.
7. Multi-machine testing for the method of using UNPIVOT instead of 10 SELECT/UNION ALLs shows that the UNPIVOT method
is quite machine dependent and can slow things down quite a bit.
-----------------------------------------------------------------------------------------------------------------------
Credits:
This code is the product of many people's efforts including but not limited to the following:
cteTally concept originally by Iztek Ben Gan and "decimalized" by Lynn Pettis (and others) for a bit of extra speed
and finally redacted by Jeff Moden for a different slant on readability and compactness. Hat's off to Paul White for
his simple explanations of CROSS APPLY and for his detailed testing efforts. Last but not least, thanks to
Ron "BitBucket" McCullough and Wayne Sheffield for their extreme performance testing across multiple machines and
versions of SQL Server. The latest improvement brought an additional 15-20% improvement over Rev 05. Special thanks
to "Nadrek" and "peter-757102" (aka Peter de Heer) for bringing such improvements to light. Nadrek's original
improvement brought about a 10% performance gain and Peter followed that up with the content of Rev 07.
I also thank whoever wrote the first article I ever saw on "numbers tables" which is located at the following URL
and to Adam Machanic for leading me to it many years ago.
-----------------------------------------------------------------------------------------------------------------------
Revision History:
Rev 00 - 20 Jan 2010 - Concept for inline cteTally: Lynn Pettis and others.
Redaction/Implementation: Jeff Moden
- Base 10 redaction and reduction for CTE. (Total rewrite)
Rev 01 - 13 Mar 2010 - Jeff Moden
- Removed one additional concatenation and one subtraction from the SUBSTRING in the SELECT List for that tiny
bit of extra speed.
Rev 02 - 14 Apr 2010 - Jeff Moden
- No code changes. Added CROSS APPLY usage example to the header, some additional credits, and extra
documentation.
Rev 03 - 18 Apr 2010 - Jeff Moden
- No code changes. Added notes 7, 8, and 9 about certain "optimizations" that don't actually work for this
type of function.
Rev 04 - 29 Jun 2010 - Jeff Moden
- Added WITH SCHEMABINDING thanks to a note by Paul White. This prevents an unnecessary "Table Spool" when the
function is used in an UPDATE statement even though the function makes no external references.
Rev 05 - 02 Apr 2011 - Jeff Moden
- Rewritten for extreme performance improvement especially for larger strings approaching the 8K boundary and
for strings that have wider elements. The redaction of this code involved removing ALL concatenation of
delimiters, optimization of the maximum "N" value by using TOP instead of including it in the WHERE clause,
and the reduction of all previous calculations (thanks to the switch to a "zero based" cteTally) to just one
instance of one add and one instance of a subtract. The length calculation for the final element (not
followed by a delimiter) in the string to be split has been greatly simplified by using the ISNULL/NULLIF
combination to determine when the CHARINDEX returned a 0 which indicates there are no more delimiters to be
had or to start with. Depending on the width of the elements, this code is between 4 and 8 times faster on a
single CPU box than the original code especially near the 8K boundary.
- Modified comments to include more sanity checks on the usage example, etc.
- Removed "other" notes 8 and 9 as they were no longer applicable.
Rev 06 - 12 Apr 2011 - Jeff Moden
- Based on a suggestion by Ron "Bitbucket" McCullough, additional test rows were added to the sample code and
the code was changed to encapsulate the output in pipes so that spaces and empty strings could be perceived
in the output. The first "Notes" section was added. Finally, an extra test was added to the comments above.
Rev 07 - 06 May 2011 - Peter de Heer, a further 15-20% performance enhancement has been discovered and incorporated
into this code which also eliminated the need for a "zero" position in the cteTally table.
**********************************************************************************************************************/
--===== Define I/O parameters
(@pString VARCHAR(8000), @pDelimiter CHAR(1))
RETURNS TABLE WITH SCHEMABINDING AS
RETURN
--===== "Inline" CTE Driven "Tally Table" produces values from 0 up to 10,000...
-- enough to cover NVARCHAR(4000)
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
;
GO
declare @temptable2 table (firstlevel varchar(200),ThirdLevel varchar(8000) )
insert into @temptable2 (firstlevel,ThirdLevel )
VALUES ('count1','serv,dan,ton'), ('count2','wers,tdan,tondrer,fhhgj,tern')
select
t.firstlevel,
ds.Item as thirdlevel
from
@temptable2 t
cross apply dbo.DelimitedSplit8k(t.ThirdLevel,',') ds;
GO
July 6, 2012 at 10:21 am
Also, be sure you read the comments and the article that is referenced in the comments, and then follow that up by reading the discussion for the article as well. You will learn much by doing so.
July 6, 2012 at 2:44 pm
i used this way
Create table #temptable2 (firstlevel varchar(200),ThirdLevel varchar(8000) ) ;
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count1','serv,dan,ton');
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count2','wers,tdan,tondrer,fhhgj,tern') ;
WITH Cte AS (
SELECT FirstLevel,
CAST('<M>' + REPLACE( ThirdLevel, ',' , '</M><M>') + '</M>' AS XML) AS ThirdLevel
FROM #temptable2
)
SELECT
FirstLevel,
Split.a.value('.', 'VARCHAR(100)') AS ThirdLevel
FROM Cte
CROSS APPLY ThirdLevel.nodes('/M') Split(a);
DROP TABLE #temptable2;
but when i joined 3 tables inner join means iam not finding the answer in ur function and my try also
July 6, 2012 at 2:59 pm
sivag (7/6/2012)
i used this way
Create table #temptable2 (firstlevel varchar(200),ThirdLevel varchar(8000) ) ;
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count1','serv,dan,ton');
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count2','wers,tdan,tondrer,fhhgj,tern') ;
WITH Cte AS (
SELECT FirstLevel,
CAST('<M>' + REPLACE( ThirdLevel, ',' , '</M><M>') + '</M>' AS XML) AS ThirdLevel
FROM #temptable2
)
SELECT
FirstLevel,
Split.a.value('.', 'VARCHAR(100)') AS ThirdLevel
FROM Cte
CROSS APPLY ThirdLevel.nodes('/M') Split(a);
DROP TABLE #temptable2;
but when i joined 3 tables inner join means iam not finding the answer in ur function and my try also
Sorry, but I'm confused. Just what are you trying to do?
July 6, 2012 at 3:40 pm
I just reran my code, and I am really confused. Based on your sample data, my code returns exactly what you asked for in your original post:
firstlevel thirdlevel
------------------------ ----------
count1 serv
count1 dan
count1 ton
count2 wers
count2 tdan
count2 tondrer
count2 fhhgj
count2 tern
(8 row(s) affected)
I have no idea what you are trying to do in your code with all the HTML (or XML) tags you are trying to add to your data as you select it.
Please provide us with a clearer, more concise description of what it is you are trying to accomplish.
July 6, 2012 at 4:42 pm
sivag (7/6/2012)
i used this way
Create table #temptable2 (firstlevel varchar(200),ThirdLevel varchar(8000) ) ;
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count1','serv,dan,ton');
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count2','wers,tdan,tondrer,fhhgj,tern') ;
WITH Cte AS (
SELECT FirstLevel,
CAST('<M>' + REPLACE( ThirdLevel, ',' , '</M><M>') + '</M>' AS XML) AS ThirdLevel
FROM #temptable2
)
SELECT
FirstLevel,
Split.a.value('.', 'VARCHAR(100)') AS ThirdLevel
FROM Cte
CROSS APPLY ThirdLevel.nodes('/M') Split(a);
DROP TABLE #temptable2;
but when i joined 3 tables inner join means iam not finding the answer in ur function and my try also
I hope you don't have too much splitting to do because that's one of the very slow ways. Here's a graphic from the following article that shows the proof. The fat pink line is your XML splitter and the fat black line is the one that Lynn was having you use. Actually, the black line is the predecessor of the fastest one. All times are based on the resolution of 10,000 rows.
http://www.sqlservercentral.com/articles/Tally+Table/72993/
--Jeff Moden
Change is inevitable... Change for the better is not.
July 6, 2012 at 4:49 pm
Jeff Moden (7/6/2012)
sivag (7/6/2012)
i used this way
Create table #temptable2 (firstlevel varchar(200),ThirdLevel varchar(8000) ) ;
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count1','serv,dan,ton');
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count2','wers,tdan,tondrer,fhhgj,tern') ;
WITH Cte AS (
SELECT FirstLevel,
CAST('<M>' + REPLACE( ThirdLevel, ',' , '</M><M>') + '</M>' AS XML) AS ThirdLevel
FROM #temptable2
)
SELECT
FirstLevel,
Split.a.value('.', 'VARCHAR(100)') AS ThirdLevel
FROM Cte
CROSS APPLY ThirdLevel.nodes('/M') Split(a);
DROP TABLE #temptable2;
but when i joined 3 tables inner join means iam not finding the answer in ur function and my try also
I hope you don't have too much splitting to do because that's one of the very slow ways. Here's a graphic from the following article that shows the proof. The fat pink line is your XML splitter and the fat black line is the one that Lynn was having you use. Actually, the black line is the predecessor of the fastest one. All times are based on the resolution of 10,000 rows.
Jeff, Was the XML splitter in your article an inline TVF or a multi-line TVF? Curious, as the splitter code posted by sivag is a multi-line TVF.
July 7, 2012 at 12:50 am
i used your function and i solved my problem
declare @temptable2 table (MainCategory varchar(200),SecondLevelCategory varchar(200),ThirdLevelCategory varchar(200) )
;WITH Cte AS (
select
distinct
a.CategoryName as MainCategory,
c.CategoryName as SecondLevelCategory,
c.Subcategories as ThirdLevelCategory
from tblbusinessurl a
inner join tblbusinessdetail b on a.BusinessUrlId =b.BusinessUrlId
inner join tblBusinessCategory c on c.BusinessDetailId=b.BusinessDetailId
cross apply dbo.characterSplit(a.CategoryName , '') ds --Replace ',' with your actual delimter
where a.CategoryName LIKE '%'+ REPLACE(RTRIM(LTRIM(ds.Items)), ' ', '%' ) + '%' and a.State='hyd' and c.Subcategories !=''
)
insert into @temptable2 (MainCategory,SecondLevelCategory,ThirdLevelCategory )
SELECT
MainCategory,
SecondLevelCategory,
ds.Item as ThirdLevelCategory
FROM Cte
cross apply dbo.DelimitedSplit8k(ThirdLevelCategory,',') ds;
select distinct MainCategory,
SecondLevelCategory,ThirdLevelCategory from @temptable2
July 7, 2012 at 12:53 am
thanks
Jeff Moden,
Lynn Pettis
for giving new idea to me
July 7, 2012 at 9:47 am
Lynn Pettis (7/6/2012)
Jeff Moden (7/6/2012)
sivag (7/6/2012)
i used this way
Create table #temptable2 (firstlevel varchar(200),ThirdLevel varchar(8000) ) ;
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count1','serv,dan,ton');
insert into #temptable2 (firstlevel,ThirdLevel ) VALUES ('count2','wers,tdan,tondrer,fhhgj,tern') ;
WITH Cte AS (
SELECT FirstLevel,
CAST('<M>' + REPLACE( ThirdLevel, ',' , '</M><M>') + '</M>' AS XML) AS ThirdLevel
FROM #temptable2
)
SELECT
FirstLevel,
Split.a.value('.', 'VARCHAR(100)') AS ThirdLevel
FROM Cte
CROSS APPLY ThirdLevel.nodes('/M') Split(a);
DROP TABLE #temptable2;
but when i joined 3 tables inner join means iam not finding the answer in ur function and my try also
I hope you don't have too much splitting to do because that's one of the very slow ways. Here's a graphic from the following article that shows the proof. The fat pink line is your XML splitter and the fat black line is the one that Lynn was having you use. Actually, the black line is the predecessor of the fastest one. All times are based on the resolution of 10,000 rows.
Jeff, Was the XML splitter in your article an inline TVF or a multi-line TVF? Curious, as the splitter code posted by sivag is a multi-line TVF.
The code posted by sivag is neither because it's not actually in a function. If it were a function, it would likely be an iTVF and, looking back at the code in the article, the XML version was an mTVF. I've not tested an iTVF version of the XML. We can, of course, fix that. I will speculate that even when converted to an iTVF, it still won't do as well as the new DelimitedSplit8K because the new splitter doesn't do any concatenation or replaces. Of course, we won't know for sure until we test.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply