September 5, 2014 at 3:51 pm
I have a text field that I need to parse out into 4 fields.
30.125x23.625-18.875x25.375
6.1875X19.375-2.4375x15.625
0X0-0x0
26.875X11.375-11.125x22.875
0X0-0x0
0X0-0x0
6.1875X26.875-2.4375x23.125
6.1875X26.875-2.4375x23.125
6.1875X26.875-2.4375x23.125
26.625X14.875-11.125x22.875
26.625X14.875-11.125x22.875
I need to 26.625X14.875-11.125x22.875 should be 26.625 then 14.875 then 11.125 then 22.875
thanks for the help
September 5, 2014 at 4:22 pm
First, for my code sample, you will need the following function. Please read the comments in the code. There is also a reference in the comments to an article on SSC that will explain more. Read it and the discussion that follows it. You should learn a lot about splitting strings by doing that.
USE [Sandbox]
GO
/****** Object: UserDefinedFunction [dbo].[DelimitedSplit8K] Script Date: 9/6/2014 02:43:45 ******/
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.
http://sqlserver2000.databases.aspfaq.com/why-should-i-consider-using-an-auxiliary-numbers-table.html
-----------------------------------------------------------------------------------------------------------------------
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
Now, what follows is my code to solve the problem you presented. First, the CTE SampleFields is nothing more than a quick means to instantiate your data in a usable format.
In the CTE I count the number rows of data and substitute a '-' for the 'X' and 'x' in the data to provide a consistent string with common delimiters. The actual work is then done in the select query following the CTE. It is basically a cross tab. Play with the code and if you have any questions, ask.
with SampleFields as (
select
SampleField = replace(upper(SampleField),'X','-'),
rn = row_number() over (order by (select null))
from (values
('30.125x23.625-18.875x25.375'),
('6.1875X19.375-2.4375x15.625'),
('0X0-0x0'),
('26.875X11.375-11.125x22.875'),
('0X0-0x0'),
('0X0-0x0'),
('6.1875X26.875-2.4375x23.125'),
('6.1875X26.875-2.4375x23.125'),
('6.1875X26.875-2.4375x23.125'),
('26.625X14.875-11.125x22.875'),
('26.625X14.875-11.125x22.875')
)dt(SampleField)
)
select
sf.SampleField,
m1 = max(case ds8k.ItemNumber when 1 then ds8k.Item else '' end),
m2 = max(case ds8k.ItemNumber when 2 then ds8k.Item else '' end),
m3 = max(case ds8k.ItemNumber when 3 then ds8k.Item else '' end),
m4 = max(case ds8k.ItemNumber when 4 then ds8k.Item else '' end)
from
SampleFields sf
cross apply dbo.DelimitedSplit8K(SampleField,'-') ds8k
group by
sf.SampleField,
sf.rn;
September 5, 2014 at 5:09 pm
This solution is an alternative which might be better or might be worse. It can be complicated because each column requires 7 functions and it won't work with 5 columns. However, it's an exercise that I like.
CREATE TABLE #SampleData(
SampleField varchar(100)
);
INSERT #SampleData
values
('30.125x23.625-18.875x25.375'),
('6.1875X19.375-2.4375x15.625'),
('0X0-0x0'),
('26.875X11.375-11.125x22.875'),
('0X0-0x0'),
('0X0-0x0'),
('6.1875X26.875-2.4375x23.125'),
('6.1875X26.875-2.4375x23.125'),
('6.1875X26.875-2.4375x23.125'),
('26.625X14.875-11.125x22.875'),
('26.625X14.875-11.125x22.875');
select SampleField,
m1 = REPLACE( PARSENAME( replace( replace(upper(REPLACE( SampleField, '.', CHAR(7))),'X','.'),'-','.'), 4), CHAR(7), '.'),
m1 = REPLACE( PARSENAME( replace( replace(upper(REPLACE( SampleField, '.', CHAR(7))),'X','.'),'-','.'), 3), CHAR(7), '.'),
m2 = REPLACE( PARSENAME( replace( replace(upper(REPLACE( SampleField, '.', CHAR(7))),'X','.'),'-','.'), 2), CHAR(7), '.'),
m3 = REPLACE( PARSENAME( replace( replace(upper(REPLACE( SampleField, '.', CHAR(7))),'X','.'),'-','.'), 1), CHAR(7), '.')
from #SampleData;
September 5, 2014 at 5:46 pm
The two solutions have very different execution plans but over the small sample dataset execution wise they are identical.
Actually, with a slight change to the code capturing stats, it actually turns out that Luis' is faster.
September 6, 2014 at 3:14 am
More for fun, I'm tossing three more spanners in the works
😎
USE tempdb;
GO
/********************************************************************
Sample data
********************************************************************/
DECLARE @SAMPLE_DATA TABLE
(
SD_ID INT IDENTITY(1,1) NOT NULL PRIMARY KEY CLUSTERED
,COL01 NVARCHAR(100) NOT NULL
);
INSERT INTO @SAMPLE_DATA (COL01)
VALUES
(N'30.125x23.625-18.875x25.375')
,(N'6.1875X19.375-2.4375x15.625')
,(N'0X0-0x0')
,(N'26.875X11.375-11.125x22.875')
,(N'0X0-0x0')
,(N'0X0-0x0')
,(N'6.1875X26.875-2.4375x23.125')
,(N'6.1875X26.875-2.4375x23.125')
,(N'6.1875X26.875-2.4375x23.125')
,(N'26.625X14.875-11.125x22.875')
,(N'26.625X14.875-11.125x22.875');
/********************************************************************
Charindex and substring parsing
********************************************************************/
SELECT
SUBSTRING(COL01,1,CHARINDEX(N'X',COL01,1)-1) AS C1
,SUBSTRING(COL01,(CHARINDEX(N'X',COL01,1) + 1),CHARINDEX(N'-',COL01,1)-(CHARINDEX(N'X',COL01,1) + 1)) AS C2
,SUBSTRING(COL01,(CHARINDEX(N'-',COL01,1) + 1),CHARINDEX(N'X',COL01,CHARINDEX(N'-',COL01,1))-(CHARINDEX(N'-',COL01,1) + 1)) AS C3
,SUBSTRING(COL01,CHARINDEX(N'X',COL01,CHARINDEX(N'-',COL01,1)) + 1,LEN(COL01)) AS C4
FROM @SAMPLE_DATA SD;
/********************************************************************
Dynamic sql parsing using the value construct (SQL Server 2008 and later)
********************************************************************/
DECLARE @SQL_STR NVARCHAR(MAX) = N'';
SELECT @SQL_STR = N'SELECT C1,C2,C3,C4 FROM (VALUES ' + STUFF((
SELECT
N',(''' + REPLACE(REPLACE(COL01,N'X',N''','''),N'-',N''',''') + N''')'
FROM @SAMPLE_DATA SD
FOR XML PATH(''), TYPE).value('.[1]','NVARCHAR(MAX)'),1,1,N'') + N') AS X( C1,C2,C3,C4 );';
EXEC (@SQL_STR);
/********************************************************************
Lead and cross tab (SQL Server 2012 and later)
********************************************************************/
;WITH T(N) AS (SELECT N FROM ( VALUES (NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL)) AS X(N))
,BASE_PARSE AS
(
SELECT
SD.COL01
,SD.SD_ID
,ROW_NUMBER() OVER
(
PARTITION BY SD.SD_ID
ORDER BY (SELECT NULL)
) AS SD_RID
,NM.N
,LEN(SD.COL01) AS LEN_COL01
FROM @SAMPLE_DATA SD
OUTER APPLY
( SELECT TOP(LEN(SD.COL01)) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS N
FROM T T1,T T2,T T3,T T4,T T5,T T6,T T7 ) AS NM(N)
WHERE SUBSTRING(SD.COL01,NM.N,1) IN (N'X',N'-')
)
,CHOPPED_PARTS AS
(
SELECT
BP.SD_ID AS SD_ID
,CASE WHEN BP.SD_RID = 1 THEN SUBSTRING(BP.COL01,1,N-1) END AS C1
,CASE WHEN BP.SD_RID = 1 THEN SUBSTRING(BP.COL01,N+1,LEAD(BP.N,1) OVER (PARTITION BY BP.SD_ID ORDER BY BP.SD_RID) - (BP.N + 1)) END AS C2
,CASE WHEN BP.SD_RID = 2 THEN SUBSTRING(BP.COL01,N+1,LEAD(BP.N,1) OVER (PARTITION BY BP.SD_ID ORDER BY BP.SD_RID) - (BP.N + 1)) END AS C3
,CASE WHEN BP.SD_RID = 3 THEN SUBSTRING(BP.COL01,N+1,LEN_COL01 - (BP.N)) END AS C4
FROM BASE_PARSE BP
)
SELECT
MAX(CP.C1) AS C1
,MAX(CP.C2) AS C2
,MAX(CP.C3) AS C3
,MAX(CP.C4) AS C4
FROM CHOPPED_PARTS CP
GROUP BY CP.SD_ID;
Results (same for all three queries)
C1 C2 C3 C4
------ ------ ------ ------
30.125 23.625 18.875 25.375
6.1875 19.375 2.4375 15.625
0 0 0 0
26.875 11.375 11.125 22.875
0 0 0 0
0 0 0 0
6.1875 26.875 2.4375 23.125
6.1875 26.875 2.4375 23.125
6.1875 26.875 2.4375 23.125
26.625 14.875 11.125 22.875
26.625 14.875 11.125 22.875
September 6, 2014 at 4:56 pm
I love problems like this because there are so many ways to accomplish them. I also like this particular post because it shows what normally occurs.... code written to solve only a very specific problem is frequently faster than generic code (even if it is DelimitedSplit8k).
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 6 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply