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


Split String with row terminator


Split String with row terminator

Author
Message
born2achieve
born2achieve
SSC Veteran
SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)

Group: General Forum Members
Points: 230 Visits: 474
Hi,

i read the below link article and and use the below function for splitting the string. I love the Jeff moden's split string and below code has modified by Aaron on top of the jeff's function.

[url=http://www.sqlperformance.com/2012/07/t-sql-queries/split-strings][/url]


CREATE FUNCTION dbo.SplitStrings_Moden
(
@List NVARCHAR(MAX),
@Delimiter NVARCHAR(255)
)
RETURNS TABLE
WITH SCHEMABINDING AS
RETURN
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),
E2(N) AS (SELECT 1 FROM E1 a, E1 b),
E4(N) AS (SELECT 1 FROM E2 a, E2 b),
E42(N) AS (SELECT 1 FROM E4 a, E2 b),
cteTally(N) AS (SELECT 0 UNION ALL SELECT TOP (DATALENGTH(ISNULL(@List,1)))
ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E42),
cteStart(N1) AS (SELECT t.N+1 FROM cteTally t
WHERE (SUBSTRING(@List,t.N,1) = @Delimiter OR t.N = 0))
SELECT Item = SUBSTRING(@List, s.N1, ISNULL(NULLIF(CHARINDEX(@Delimiter,@List,s.N1),0)-s.N1,8000))
FROM cteStart s;



I literally need to have passing string as MAX which is excellent on the above function. Basically i am reading text file from my front end and passing the entire text to back end for splitting with delimiter and ROWTERMINATOR [backward slash n]

please don't ask about why am doing this as i can use bulk insert for moving the data from text file to my db table. because i cannot have my text file on the database server to copy the record with bulk insert feature.

my sample data which needs to be split with delimiter and ROWTERMINATOR [backward slash n]


'2D5E558D4B5A3D4F962DA5051EE364BE06CF37A3A5@Server.com|user1@domain1.com
E52F650C53A275488552FFD49F98E9A6BEA1262E@Server.com|user2@domain2.com
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user3@domain3.com
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user4@domain4.com
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com |user5@domain5.com'



on the above example delimiter is '|' and ROWTERMINATOR is [backward slash n]

Expected output as two columns with 5 rows

please execute the below query to see how the expected output will be


select '2D5E558D4B5A3D4F962DA5051EE364BE06CF37A3A5@Server.com' as server, 'user1@domain1.com' as domain union all
select 'E52F650C53A275488552FFD49F98E9A6BEA1262E@Server.com' as server, 'user2@domain2.com' as domain union all
select '4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com' as server, 'user3@domain3.com' as domain union all
select '4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com'as server,'user4@domain4.com' as domain union all
select '4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com'as server,'user5@domain5.com'



is there any way to achieve this. is yes please suggest me with some sample

Thanks.
Adi Cohn-120898
Adi Cohn-120898
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2222 Visits: 6076
I don't think that you need to work with a user defined function. Take a look at the code bellow. Is that what you need? Notice that I added a select with the union all. You didn't have it in your example, but without it, you'll have a run time error (that’s assuming that you wanted to select this data).

declare @MyString varchar(max)

set @MyString = '2D5E558D4B5A3D4F962DA5051EE364BE06CF37A3A5@Server.com|user1@domain1.com
E52F650C53A275488552FFD49F98E9A6BEA1262E@Server.com|user2@domain2.com
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user3@domain3.com
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user4@domain4.com
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com |user5@domain5.com'

select @MyString = 'SELECT ''' + replace(replace(@MyString,'|', ''' as server, '''),'
',''' as domain union all
select ''') + ''' as domain'

select @MyString
exec(@MyString)




Adi

--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
born2achieve
born2achieve
SSC Veteran
SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)

Group: General Forum Members
Points: 230 Visits: 474
Hi Adi,

Thanks for your reply and sample. I just gave the sample data. Here is the table structure which i will import the query output to the table.


Create table DataFiles(IdData int identity(1,1) primary key,
server nvarchar(4000),domain nvarchar(50),
ReceivedFilescount int,DateReceived date,
company varchar(50),ExpectedFilesCount int)



Sample data

'2D5E558D4B5A3D4F962DA5051EE364BE06CF37A3A5@Server.com|user1@domain1.com|0|2014-02-05|Microsoft|100
E52F650C53A275488552FFD49F98E9A6BEA1262E@Server.com|user2@domain2.com|1|2014-03-05|Samsumg|120
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user3@domain3.com|2|2014-01-05|Nokia|139
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user4@domain4.com|3|2014-02-08|HTC|149
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com |user5@domain5.com|4|2014-02-13|Paypal|129'



I should have been given whole data. my mistake. sorry about that. Also please note that there will be an addition to this data in future as well as on the new columns on my table.

So on your sample you have user Replace function for making the column name, and constructing the column name with select statement. if there is more column then construction will be cumbersome.

Is there any other way to achieve this or how to simplify your query ?
Adi Cohn-120898
Adi Cohn-120898
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2222 Visits: 6076
Ectualy you don't need to name the columns in the select statement, so you can still use 2 replace statements and it will work. You can check the code bellow that inserts the data into the table

Create table DataFiles(IdData int identity(1,1) primary key,
server nvarchar(4000),domain nvarchar(50),
ReceivedFilescount int,DateReceived date,
company varchar(50),ExpectedFilesCount int)

declare @SQL varchar(max)
declare @MyString varchar(max) =
'2D5E558D4B5A3D4F962DA5051EE364BE06CF37A3A5@Server.com|user1@domain1.com|0|2014-02-05|Microsoft|100
E52F650C53A275488552FFD49F98E9A6BEA1262E@Server.com|user2@domain2.com|1|2014-03-05|Samsumg|120
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user3@domain3.com|2|2014-01-05|Nokia|139
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user4@domain4.com|3|2014-02-08|HTC|149
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com |user5@domain5.com|4|2014-02-13|Paypal|129'

select @MyString = 'SELECT ''' +replace(replace(@MyString,'|',''','''),'
',''' union select
''') + ''''

select @MyString
exec (@MyString)

set @SQL = 'INSERT INTO DataFiles(server, domain, ReceivedFilescount, DateReceived, company, ExpectedFilesCount)
' + @MyString

exec (@SQL)

select * from DataFiles




Although the code works, I think that you should look on working with bulk insert statement or BCP. In my opinion it is more suitable then using my code.

Adi

--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44981 Visits: 39869
born2achieve (3/15/2014)
Hi,

i read the below link article and and use the below function for splitting the string. I love the Jeff moden's split string and below code has modified by Aaron on top of the jeff's function.


That's a bad modification, IMHO, and I wouldn't be tempted to use it for anything important.

First, the input has been changed to a MAX datatype but the largest number that can come of the cascading CTE will only support a million characters. Since it's an NVARCHARMAX, it needs to support a billion characters and a count of 2 billion.

Second, the delimiter has been changed from 1 character to 255. If you don't have multicharacter delimiters all that's going to do is slow things down.

Third, the code hasn't been modified to work with a multicharacter delimiter and it will lead to some pretty bad returns if you ever use one.

Fourth, if the final element is longer than 8000 characters, it will be truncated because the code wasn't setup to handle NVARCHAR(MAX) correctly.

Last, the code isn't close to the latest, higher performance version.

As a bit of a sidebar, the reason why I didn't write this to handle the MAX datatypes is because blobs don't like to be joined to. Using a MAX datatype here will cause it to perform at least 2 times slower even if you pass it something less than 8000 characters.

My recommendation is that if you need to split things that live in a MAX datatype, then either use BCP/BULK INSERT to load it or use a well written CLR to split it.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
     Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is usually not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
born2achieve
born2achieve
SSC Veteran
SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)

Group: General Forum Members
Points: 230 Visits: 474
Hi Adi, thanks for your reply, sample and appreciate your time on this post.

Hi Jeff,

Thanks for your reply

So from your statement it's not good to use the function which i mentioned because of the performance impact. I understand. How about Adi's Suggestion. Logically it works with my data. is there any performance impact on this suggestion.

Please suggest me
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44981 Visits: 39869
born2achieve (3/16/2014)
Hi Adi, thanks for your reply, sample and appreciate your time on this post.

Hi Jeff,

Thanks for your reply

So from your statement it's not good to use the function which i mentioned because of the performance impact. I understand. How about Adi's Suggestion. Logically it works with my data. is there any performance impact on this suggestion.

Please suggest me


No... it's not good to use the function because the changes you said Aaron made are not sufficient for what it's supposed to do. It could return wrong or truncated information without you ever knowing about it.

As for Adi's suggestion, I'll have to take a look.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
     Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is usually not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
born2achieve
born2achieve
SSC Veteran
SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)

Group: General Forum Members
Points: 230 Visits: 474
Thank you Jeff for rescuing me from Aaron's modified function. I understand the cause from your explanation. Please post your comment about Adi's suggestion.

Thank you
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44981 Visits: 39869
I don't know how many "rows" will be in each string that you get. If it's more than a couple hundred, Adi's good code is going to get real slow. If it's more than that, it will eventually fail because you can only have a certain number of SELECTs per query. Adi's code is also subject to SQL Injection attacks.

You can make his code a little faster and a lot safer if you make the small changes that I've included below to the one section of code that it represents.

select @MyString = 'SELECT ''' +replace(replace(@MyString,'|',''','''),'
',''' union ALL select
''') + ''''
WHERE @MyString NOT LIKE '%[^-a-zA-Z0-9@|.'+CHAR(10)+CHAR(13)+']%'




I agree with Adi... this is a job better done by BULK INSERT or BCP. BCP won't have the same server-to-server trust problems as BULK INSERT so that may be the way to go here.

If even that is not allowed, then a well written CLR would serve you better than any manifestation of the DelimitedSplit8K function or Adi's good code.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
     Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is usually not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
born2achieve
born2achieve
SSC Veteran
SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)SSC Veteran (230 reputation)

Group: General Forum Members
Points: 230 Visits: 474
Hi Jeff,

Thank you so much for your wonderful time on this post and it really helped me. i tried to incorporate your changes on Adi's query and getting error. It doesn't say any clue about the issue.


declare @SQL varchar(max)
declare @MyString varchar(max) =
'2D5E558D4B5A3D4F962DA5051EE364BE06CF37A3A5@Server.com|user1@domain1.com|0|2014-02-05|Microsoft|100
E52F650C53A275488552FFD49F98E9A6BEA1262E@Server.com|user2@domain2.com|1|2014-03-05|Samsumg|120
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user3@domain3.com|2|2014-01-05|Nokia|139
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com|user4@domain4.com|3|2014-02-08|HTC|149
4fd70c47.4d600e0a.0a7b.ffff87e1@Server.com |user5@domain5.com|4|2014-02-13|Paypal|129'

select @MyString = 'SELECT ''' +replace(replace(@MyString,'|',''','''),'
',''' union ALL select
''') + ''''
WHERE @MyString NOT LIKE '%[^-a-zA-Z0-9@|.'+CHAR(10)+CHAR(13)+']%'

--select @MyString
--exec (@MyString)

set @SQL = 'INSERT INTO DataFiles(server, domain, ReceivedFilescount, DateReceived, company, ExpectedFilesCount)
' + @MyString

exec (@SQL)



Any suggestion please
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