SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2008 Forums
 Transact-SQL (2008)
 get only the alphabets
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

sqllover
Constraint Violating Yak Guru

India
331 Posts

Posted - 09/12/2013 :  16:59:29  Show Profile  Reply with Quote
i have productname column in my table and the query i need to get only the alphabets.

column contains the special characters(,.-@/), numbers(0-9), space

sample data


Foodhold USA,mlc.
Beverage Partners Worldwide (North canada)......
Bread World 8


my expected output will be

FoodholdUSAmlc
BeveragePartnersWorldwide(Northcanada)
BreadWorld



SELECT productname,  
SUBSTRING(Name,1,ISNULL(NULLIF(PATINDEX('%[^A-Za-z.''0-9]%',LTRIM(RTRIM(productname))),0)-1,LEN(productname))) AS noSpecials
 FROM Manufacturer 



but it is not working. can anyone please show me sample query..

sqllover
Constraint Violating Yak Guru

India
331 Posts

Posted - 09/12/2013 :  17:08:46  Show Profile  Reply with Quote
small addition,

i want to strip below special characters as well
!@#$%^&*():'"{}[]\|?-+=
Go to Top of Page

sqllover
Constraint Violating Yak Guru

India
331 Posts

Posted - 09/12/2013 :  17:11:31  Show Profile  Reply with Quote
small addition,

i want to strip below special characters as well
!@#$%^&*():'"{}[]\|?-+=
Go to Top of Page

James K
Flowing Fount of Yak Knowledge

3575 Posts

Posted - 09/12/2013 :  17:20:27  Show Profile  Reply with Quote
Here is an example of how you can do this. This filters in characters. With some minor changes you can make it filter out characters as well.
CREATE TABLE #tmp (n INT, x VARCHAR(64));
INSERT INTO #tmp VALUES (1,'Foodhold USA,mlc.'),(2,'Beverage Partners Worldwide (North canada)......')

-- characters you want to keep
DECLARE @valuesToKeep VARCHAR(128) = 'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz()';

-- if you plan to use it in production, replace the spt_values with a Numbers table.
SELECT
	a.n,
	b.Alphabets
FROM
	#tmp a
	CROSS APPLY 
	(
		SELECT
			SUBSTRING(x,number+1,1)
		FROM
			#tmp t
			INNER JOIN master.dbo.spt_values s ON
				s.number < LEN(t.x)
		WHERE
			s.type = 'P'
			AND @valuesToKeep COLLATE Latin1_General_CS_AS  LIKE 
				'%' + SUBSTRING(x,number+1,1) + '%' 
			AND t.n = a.n
		FOR XML PATH('')
	) b(Alphabets);
	
DROP TABLE #tmp;
Go to Top of Page

VeeranjaneyuluAnnapureddy
Posting Yak Master

India
165 Posts

Posted - 09/13/2013 :  01:51:13  Show Profile  Reply with Quote
USE DBTraining1
GO
IF OBJECT_ID('fn_GetAlphabets') Is Not Null
DROP FUNCTION dbo.fn_GetAlphabets
GO
CREATE FUNCTION fn_GetAlphabets(@input VARCHAR(20))
RETURNS VARCHAR(1000)
AS
BEGIN
WHILE PATINDEX('%[^a-z]%',@input) > 0
SET @input = STUFF(@input,PATINDEX('%[^a-z]%',@input),1,'')
RETURN @input
END


SELECT * FROM TableName
WHERE dbo.fn_GetAlphabets(TableName.ProductName) = TableName.ProductName

veeranjaneyulu
Go to Top of Page

sqllover
Constraint Violating Yak Guru

India
331 Posts

Posted - 09/13/2013 :  07:26:37  Show Profile  Reply with Quote
Thanks James and veera for the best knowledge. Appreciate your time on this post
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.06 seconds. Powered By: Snitz Forums 2000