Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

split column into multiple records based on substring fixed lenght Expand / Collapse
Author
Message
Posted Wednesday, December 11, 2013 10:22 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, June 20, 2014 3:12 PM
Points: 146, Visits: 141
I have seen posts to split column into multiple records based on delimited value.

I need to split a vchar(4000) column into multiple records into column vchar(80)
based on substring if not blank

I can use the below code...would be okay if original column was only vchar(400)
but obviously there has to be a better way to loop thru.

Thanks for the help in advance.

SELECT cust, SUBSTRING(wptext, 1, 80) AS wptext, 1 as seq
FROM TableA WHERE SUBSTRING(wptext, 1, 80) <> ' '
UNION ALL
SELECT cust, SUBSTRING(wptext, 81, 80) AS wptext, 2 as seq
FROM TableA WHERE SUBSTRING(wptext, 81, 80) <> ' '
UNION ALL
SELECT cust, SUBSTRING(wptext, 161, 80) AS wptext, 3 as seq
FROM TableA WHERE SUBSTRING(wptext, 161, 80) <> ' '
UNION ALL
SELECT cust, SUBSTRING(wptext, 241, 80) AS wptext, 4 as seq
FROM TableA WHERE SUBSTRING(wptext, 241, 80) <> ' '
UNION ALL
SELECT cust, SUBSTRING(wptext, 321, 80) AS wptext, 5 as seq
FROM TableA WHERE SUBSTRING(wptext, 321, 80) <> ' '
order by cust, seq



Post #1521975
Posted Wednesday, December 11, 2013 10:42 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 5:52 PM
Points: 3,325, Visits: 7,172
A Tally table (or in this case a cteTally) can come to the rescue.
Check the following code and ask for anything that you don't understand.

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
),
cteTally(n) AS(
SELECT TOP 50 ROW_NUMBER() OVER( ORDER BY ( SELECT NULL))
FROM E1, E1 b
)
SELECT cust, SUBSTRING(wptext, (80 * (n-1)) + 1, 80 ) AS wptext, n as seq
FROM TableA a
JOIN cteTally t ON t.n <= CEILING( LEN( a.wptext) / 80.0)
order by cust, n




Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1521983
Posted Wednesday, December 11, 2013 11:06 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 12:51 PM
Points: 1,072, Visits: 6,336
SELECT x.*
FROM TableA
CROSS APPLY (
SELECT cust, SUBSTRING(wptext, 1, 80), 1 UNION ALL
SELECT cust, SUBSTRING(wptext, 81, 80), 2 UNION ALL
SELECT cust, SUBSTRING(wptext, 161, 80), 3 UNION ALL
SELECT cust, SUBSTRING(wptext, 241, 80), 4 UNION ALL
SELECT cust, SUBSTRING(wptext, 321, 80), 5
) x (cust, wptext, seq)




Low-hanging fruit picker and defender of the moggies





For better assistance in answering your questions, please read this.




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
Post #1521992
Posted Wednesday, December 11, 2013 12:16 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, June 20, 2014 3:12 PM
Points: 146, Visits: 141
The Tally Table appears to be what I am looking to do.
I will verify some of the results but initial return values look okay.
So the code has several "SELECT 1 UNION ALL"...how do you know how many to use?
The code also uses "SELECT TOP 50 ROW_NUMBER()"....how do you know to use 50?

Thanks again for the help!



Post #1522014
Posted Wednesday, December 11, 2013 12:23 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, June 20, 2014 3:12 PM
Points: 146, Visits: 141
on side note....how do you post the script inside the window box. I read best practice for posting but not seeing it.
Do you use the IFCode Shortcuts...still not quite sure how those work either.



Post #1522017
Posted Wednesday, December 11, 2013 12:30 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 5:52 PM
Points: 3,325, Visits: 7,172
All the "SELECT 1 UNION ALL" create 10 rows which I later use to create 100 rows with a CROSS JOIN in the next CTE.
I'm using TOP 50 because you said that you have a varchar(4000) and 4000/80 = 50.
You can change the value to any value you need or just remove it.

To put your code in the code box you use the IFCode Shortcuts. Either you click on the [ code="sql"] one before inserting the code and then put the code between the labels or you can select the code and click on the shortcut to put the labels around your selection.



Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1522022
Posted Thursday, December 12, 2013 10:07 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, June 20, 2014 3:12 PM
Points: 146, Visits: 141
So I was able to split column based on specific substring length and export the data to my target source; at which point I noticed data contained Line Feed.
So is there a way to split column into multiple records based on Line Feed and excluding Line Feed char(10)

Thanks again in advance for your help.



Post #1522394
Posted Thursday, December 12, 2013 10:13 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 5:52 PM
Points: 3,325, Visits: 7,172
I need you to post sample data and expected results, because I'm not sure that I understand the problem. To know how to do it, please read the article linked on my signature.


Luis C.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1522396
Posted Thursday, December 12, 2013 10:34 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 8:49 AM
Points: 7,047, Visits: 6,790
Richard Cranston (12/12/2013)
So I was able to split column based on specific substring length and export the data to my target source; at which point I noticed data contained Line Feed.
So is there a way to split column into multiple records based on Line Feed and excluding Line Feed char(10)

Thanks again in advance for your help.


See Jeff Moden's splitter at http://www.sqlservercentral.com/articles/Tally+Table/72993/
and use CHAR(10) as the delimiter



Far away is close at hand in the images of elsewhere.

Anon.

Post #1522407
Posted Thursday, December 12, 2013 10:45 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, June 20, 2014 3:12 PM
Points: 146, Visits: 141
CREATE TABLE [dbo].[tableA](
[CUST] [varchar](9) NOT NULL,
[WPTEXT] [varchar](4000) NULL)

INSERT INTO tableA values ('12345' ,
'6/26/08 BAD DEBT 1,351.28 BANKRUPT C-11' + CHAR(10) +
'07/03/08 BAD DEBT RECOVERY 273.07 BAL OWED 1,078.21.' + CHAR(10) +
'09/17/09 BAD DEBT RECOVERY 462.07 BAL OWED 616.14.' + CHAR(10) +
'06/29/09 OVER PAYMENTS USED AGAINST BAD DEBT. (196.81)' + CHAR(10) +
'BALANCE OWED 419.33.' + CHAR(10) +
'11/30/09 BAD DEBT RECOVERY 1.70 BAL OWED 417.63.' + CHAR(10) +
'12/23/10-BAD DEBT RECOVERY 10.20 BAL OWED 407.43.')

SELECT cust, wptext, charindex(char(10), wptext) as firstposlinefeed
FROM tableA where charindex(char(10), wptext) <> 0

Hope this code is helpful



Post #1522413
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse