Important alert: (current site time 7/15/2013 7:09:03 PM EDT)
 

VB icon

Column From Delimited String

Email
Submitted on: 1/7/2003 9:20:02 AM
By: Sean P. O. MacCath-Moran  
Level: Intermediate
User Rating: By 1 Users
Compatibility: SQL Server 2000, SQL Server 7.0
Views: 12877
(About the author)
 
     This function returns a column as a string from the provided delimited string, taking in to account the specified field delimiter and text qualifiers. In my own use if this, I perform a BULK INSERT operation into a table and then build a new table based on previously defined field definitions stored in yet another table. This function should handle most delimitation needs, though I did not spend a lot of time making sure it was fully generic as I had a fairly narrow scope I needed for it to fill. KEYWORDS: csv, delimited, import
 
code:
Can't Copy and Paste this?
Click here for a copy-and-paste friendly version of this code!
 
Terms of Agreement:   
By using this code, you agree to the following terms...   
  1. You may use this code in your own programs (and may compile it into a program and distribute it in compiled format for languages that allow it) freely and with no charge.
  2. You MAY NOT redistribute this code (for example to a web site) without written permission from the original author. Failure to do so is a violation of copyright laws.   
  3. You may link to this code from another website, but ONLY if it is not wrapped in a frame. 
  4. You will abide by any additional copyright restrictions which the author may have placed in the code or code's description.
				
--**************************************
-- Name: Column From Delimited String
-- Description:This function returns a column as a string from the provided delimited string, taking in to account the specified field delimiter and text qualifiers. In my own use if this, I perform a BULK INSERT operation into a table and then build a new table based on previously defined field definitions stored in yet another table. This function should handle most delimitation needs, though I did not spend a lot of time making sure it was fully generic as I had a fairly narrow scope I needed for it to fill.
KEYWORDS: csv, delimited, import
-- By: Sean P. O. MacCath-Moran
--
-- Inputs:-
/*@RowText: The delimited string from which the column's data will be extracted.
@FieldDelimiter: The string that indicates a seperation of columns.
@TextQualifier: The string that indicates a text value.
@Column: The column of data to return. The value of @Column must be greater than 0.
*/
--
-- Returns:-
/*
Returns the location of one string within another with parameterized constraints
*/
--
-- Assumes:-
/*
1) It is ok for a field delimiter to occur within a field enclosed by the text qualifiers
2) Two text qualifiers, one following the other, is meant to indicate a single text qualifier in the output.
3) A field that has a starting and ending text qualifier will have those characters removed from the return string.
4) A field that begins with a text qualifier will end with a text qualifier.
*/
--
--This code is copyrighted and has-- limited warranties.Please see http://www.Planet-Source-Code.com/vb/scripts/ShowCode.asp?txtCodeId=619&lngWId=5--for details.--**************************************

SET QUOTED_IDENTIFIER OFF 
GO
SET ANSI_NULLS OFF 
GO
/*
Description:	
	DFCol: Delimited File Column
	Returns the location of one string within another with parameterized constraints:
		@RowText: The delimited string from which the column's data will be extracted.
		@FieldDelimiter: The string that indicates a seperation of columns.
		@TextQualifier: The string that indicates a text value.
		@Column: The column of data to return. The value of @Column must be greater than 0.
 	 MODULE	 TableName	Date/Time
	DATE		BY				CHANGE
	12/26/2002	Sean P. O. MacCath-Moran	Created
*/
CREATE FUNCTION fn_cnv_GetDelimitedColumn (
	@RowText varchar(200), 
	@FieldDelimiter varchar(10),
	@TextQualifier varchar(10),
	@Column int)
RETURNS varchar(200)
AS
BEGIN
	DECLARE @ColStart int, @EndTQualCol int, @TempString varchar(6000), @TQualFound int, @ColumnsIdentified int, @ColEnd int, @ReturnValue varchar(8000)
	
	/*Make sure we have valid perameters*/
	IF @RowText IS NULL OR @FieldDelimiter IS NULL OR @TextQualifier IS NULL OR @Column < 1
	 BEGIN
		/*Cannot perform search with these values*/
		RETURN NULL
	 END
	IF LEN(@RowText) = 0 OR LEN(@FieldDelimiter) = 0 OR LEN(@RowText) < LEN(@FieldDelimiter)
	 BEGIN
		/*Cannot perform search with these values*/
		RETURN NULL
	 END
	SET @ColumnsIdentified = 0
	SET @TQualFound = 0
	SET @ColStart = -1
	SET @ColEnd = -1
	IF @Column > 0
	 BEGIN
		/*Determine where this column begins*/
		WHILE @ColumnsIdentified < @Column
		/*Loop through @RowText and find the @Column instance of @FieldDelimiter*/
		 BEGIN
			IF CHARINDEX(@FieldDelimiter, @RowText, @ColStart) = 0 AND @Column != (@ColumnsIdentified + 1)
			/*If it is NOT != then this is the last column and it is the column being sought*/
			 BEGIN
				RETURN NULL
			 END
			/*An instance of @FieldDelimiter has been located.*/
			IF @ColStart = -1
				SET @ColStart = 1
			ELSE
			 BEGIN
				SET @ColStart = CHARINDEX(@FieldDelimiter, @RowText, @ColStart) 
				/*If @ColStart is 0 here then there are no more columns to find...*/
				IF @ColStart = 0
					RETURN NULL
				ELSE
					SET @ColStart = @ColStart + LEN(@FieldDelimiter)
			 END
			SET @EndTQualCol = @ColStart
			WHILE SUBSTRING(@RowText,@ColStart,LEN(@TextQualifier)) = @TextQualifier
			/*If the @ColStart detected begins with a text qualifier...*/
			 BEGIN
				SET @ColEnd = CHARINDEX(@TextQualifier+@FieldDelimiter,@RowText,@EndTQualCol)
	
				/*IF a field and text qualifier combo is found then use that position. If not, then if the last 
				 character in the row isa textqualifier then use that. If not, then something has gone wrong - 
				 return a null*/
				IF @ColEnd > 0
					SET @ColEnd = @ColEnd + LEN(@TextQualifier)
				ELSE IF SUBSTRING(@RowText,LEN(@RowText)-LEN(@TextQualifier)+1,LEN(@TextQualifier)) = @TextQualifier
					SET @ColEnd = LEN(@RowText) + 1
				ELSE
					RETURN NULL
	
				SET @TempString = SUBSTRING(@RowText,@ColStart,@ColEnd - @ColStart)
				/*Discover how many occurances of @TextQualifier exist in @TempString*/
				WHILE 1=1
				 BEGIN
					IF CHARINDEX(@TextQualifier,@TempString,1)>0
					 BEGIN
						SET @TempString = SUBSTRING(@TempString,CHARINDEX(@TextQualifier,@TempString,1) + LEN(@TextQualifier),LEN(@TempString))
						SET @TQualFound = @TQualFound + 1
					 END
					ELSE
						BREAK
				 END
				/*IF there are an odd number of @TQualFound then this is not the end of the column...*/
				IF (@TQualFound % 2) > 0 
				 BEGIN
					SET @EndTQualCol = @ColEnd
					SET @TQualFound = 0
				 END
				ELSE
					BREAK
				
			 END
			SET @ColumnsIdentified = @ColumnsIdentified + 1
			IF @ColumnsIdentified < @Column AND @ColEnd > -1
			 BEGIN
				SET @ColStart = @ColEnd
				SET @ColEnd = -1
			 END
		 END
	 END
	
	/*Determine where this column ends if not done so by the previous steps*/
	IF @ColEnd = -1
	 BEGIN
		SET @ColEnd = CHARINDEX(@FieldDelimiter, @RowText, @ColStart)
		IF @ColEnd = 0 SET @ColEnd = LEN(@RowText) + 1
	 END
	
	SET @ReturnValue = SUBSTRING(@RowText,@ColStart,@ColEnd - @ColStart)
	
	/*This line reduces all double occurances of @TextQualifier to single occurances*/
	SET @ReturnValue = REPLACE(@ReturnValue,@TextQualifier+@TextQualifier,@TextQualifier)
	/*These two lines strip a @TextQualifier off of either side of the return value if such a character is there.*/
	IF SUBSTRING(@ReturnValue,1,LEN(@TextQualifier)) = @TextQualifier SET @ReturnValue = SUBSTRING(@ReturnValue,LEN(@TextQualifier)+1,8000)
	IF SUBSTRING(@ReturnValue,LEN(@ReturnValue)-LEN(@TextQualifier)+1,LEN(@TextQualifier)) = @TextQualifier SET @ReturnValue = SUBSTRING(@ReturnValue,1,LEN(@ReturnValue)-LEN(@TextQualifier))
	
	IF LEN(@ReturnValue) = 0 SET @ReturnValue = NULL
	RETURN @ReturnValue
END
GO
SET QUOTED_IDENTIFIER OFF 
GO
SET ANSI_NULLS ON 
GO


Other 4 submission(s) by this author

 


Report Bad Submission
Use this form to tell us if this entry should be deleted (i.e contains no code, is a virus, etc.).
This submission should be removed because:

Your Vote

What do you think of this code (in the Intermediate category)?
(The code with your highest vote will win this month's coding contest!)
Excellent  Good  Average  Below Average  Poor (See voting log ...)
 

Other User Comments

 There are no comments on this submission.
 

Add Your Feedback
Your feedback will be posted below and an email sent to the author. Please remember that the author was kind enough to share this with you, so any criticisms must be stated politely, or they will be deleted. (For feedback not related to this particular code, please click here instead.)
 

To post feedback, first please login.