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


split column into multiple records based on substring fixed lenght


split column into multiple records based on substring fixed lenght

Author
Message
Richard Cranston
Richard Cranston
SSC-Enthusiastic
SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)

Group: General Forum Members
Points: 164 Visits: 158
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



Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8566 Visits: 18143
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.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
ChrisM@home
ChrisM@home
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1163 Visits: 9736
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
Richard Cranston
Richard Cranston
SSC-Enthusiastic
SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)

Group: General Forum Members
Points: 164 Visits: 158
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!



Richard Cranston
Richard Cranston
SSC-Enthusiastic
SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)

Group: General Forum Members
Points: 164 Visits: 158
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.



Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8566 Visits: 18143
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.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Richard Cranston
Richard Cranston
SSC-Enthusiastic
SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)

Group: General Forum Members
Points: 164 Visits: 158
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.



Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8566 Visits: 18143
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.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
David Burrows
David Burrows
SSCertifiable
SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)

Group: General Forum Members
Points: 7968 Visits: 9425
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.


Richard Cranston
Richard Cranston
SSC-Enthusiastic
SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)SSC-Enthusiastic (164 reputation)

Group: General Forum Members
Points: 164 Visits: 158

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



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