March 15, 2014 at 4:01 pm
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.
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.
March 16, 2014 at 2:27 am
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/
March 16, 2014 at 7:12 am
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 ?
March 16, 2014 at 11:35 am
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/
March 16, 2014 at 3:13 pm
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
Change is inevitable... Change for the better is not.
March 16, 2014 at 3:34 pm
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
March 16, 2014 at 3:57 pm
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
Change is inevitable... Change for the better is not.
March 16, 2014 at 4:42 pm
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
March 16, 2014 at 5:06 pm
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
Change is inevitable... Change for the better is not.
March 16, 2014 at 5:59 pm
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
March 16, 2014 at 6:30 pm
Jeff Moden (3/16/2014)
then either use BCP/BULK INSERT to load it or use a well written CLR to split it.
+1
...Or split the text in your front end application (that is currently sending it all as a blob) and then bulk insert it.
Is there a good reason why you are asking SQL to perform this string manipulation instead of handling it before it gets to SQL?
MM
select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);
March 16, 2014 at 7:09 pm
would like to try all possible way to do this and which ever is taking lesser time will be used. i am going to try bulk insert from my front end and as well as jeff and adis' query as another try. based on the time consuming will finalize which should i use.
thanks for taking time on this post. just trying to get the query error solved after adding jeff's Logic. Any suggestion please
March 16, 2014 at 7:19 pm
What is the error and what is the output of
Print @MyString
?
MM
select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);
March 16, 2014 at 7:23 pm
error :
Msg 102, Level 15, State 1, Line 2
Incorrect syntax near '2'.
Print result
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
Any suggestion please
March 16, 2014 at 7:29 pm
Jeff's addition of the WHERE clause is designed to prevent SQL Injection and possible data corruption by only allowing data that conforms to the listed character sets.
You have an illegal character at position 407 - it is ASCII 0xF6 (the division symbol).
This character has been caught by Jeff's predicate.
MM
select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);
Viewing 15 posts - 1 through 15 (of 17 total)
You must be logged in to reply to this topic. Login to reply