March 4, 2015 at 2:23 pm
in my table I have values such as
Admin -- Assistants
Finance -- Accountant
Underwriting
I have code in the query to remove [value --] so its returned as
Assistant
Accountant
Underwritin
however, if the value doesn't have [--], its remove the last character of the value (as underwritin)
am I missing something in this, or is there another way to remove the text and the dashes if it exists?
REPLACE(SUBSTRING([family],
CHARINDEX('--', [family]),
LEN([family])), '--', '') AS [JobTitles]
March 4, 2015 at 2:35 pm
The CHARINDEX gives you a 0 if there is no --
When you use 0 as the start position for substring it messes it up. Here is the MSDN page on SUBSTRING.
Take note of the following about START:
Is an integer or bigint expression that specifies where the returned characters start. If start is less than 1, the returned expression will begin at the first character that is specified in expression. In this case, the number of characters that are returned is the largest value of either the sum of start + length- 1 or 0. If start is greater than the number of characters in the value expression, a zero-length expression is returned.
March 4, 2015 at 2:44 pm
LEFT(family, CHARINDEX('--', [family] + '--') - 2)
Edit: Added the "- 2".
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
March 4, 2015 at 3:18 pm
What's wrong with just doing a replacement?
UPDATE tgt
SET Family = REPLACE(Family,'--','')
FROM dbo.yourtable
WHERE Family LIKE '%--%'
;
--Jeff Moden
Change is inevitable... Change for the better is not.
March 4, 2015 at 3:30 pm
Jeff Moden (3/4/2015)
What's wrong with just doing a replacement?
UPDATE tgt
SET Family = REPLACE(Family,'--','')
FROM dbo.yourtable
WHERE Family LIKE '%--%'
;
there are other apps using the tables that I'm pulling from, so we can't do an update. It crossed my mind, but can't.
March 4, 2015 at 3:35 pm
SQL_NuB (3/4/2015)
Jeff Moden (3/4/2015)
What's wrong with just doing a replacement?
UPDATE tgt
SET Family = REPLACE(Family,'--','')
FROM dbo.yourtable
WHERE Family LIKE '%--%'
;
there are other apps using the tables that I'm pulling from, so we can't do an update. It crossed my mind, but can't.
Yeah, I'd be extremely careful before just arbitrarily discarding potential delimiters in a column value.
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
March 4, 2015 at 4:26 pm
SQL_NuB (3/4/2015)
Jeff Moden (3/4/2015)
What's wrong with just doing a replacement?
UPDATE tgt
SET Family = REPLACE(Family,'--','')
FROM dbo.yourtable
WHERE Family LIKE '%--%'
;
there are other apps using the tables that I'm pulling from, so we can't do an update. It crossed my mind, but can't.
Ah, crud. I totally misread the original post. My apologies.
--Jeff Moden
Change is inevitable... Change for the better is not.
March 4, 2015 at 5:08 pm
ScottPletcher (3/4/2015)
LEFT(family, CHARINDEX('--', [family] + '--') - 2)Edit: Added the "- 2".
when I add this, its removing the text before the [--].
March 4, 2015 at 5:54 pm
Late to the party, but perhaps this does what you're looking for:
WITH SampleData (s) AS
(
SELECT 'Admin -- Assistants'
UNION ALL SELECT 'Finance -- Accountant'
UNION ALL SELECT 'Underwriting'
)
SELECT s, REPLACE(STUFF(s, 1, CHARINDEX('--', s), ''), '- ', '')
FROM SampleData;
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply