October 4, 2012 at 4:05 pm
Hello,
I'm new to these forums & need some help putting together a T-SQL query for selecting some info from my db. On the table I'm attempting to query there is a column called lastname that holds multiple last names for customers. Rows that have more than one last name are separated by a '/' character, no spaces are between the '/' and the last names.
I want to select customers with two last names, for instance customers like 'garcia/fish' or 'johnson-howard/bobby-ray'.
Is there a way to select only rows that have one '/' entered in the character string? I don't want last names like 'davis/cameron/lew'. Oh, forgot to mention that the column is of type nvarchar. I assume that something like:
select lastname
from HR.Employees
where lastname LIKE '[/]';
would select entries that have '/'s however I'm not getting any results & I need ONLY rows that have one '/'
Hope this makes sense, I realize it's a pretty vague example however I'd be extremely grateful if anyone here can help me.
October 4, 2012 at 4:09 pm
Chain your charindexes.
Basically, you'll want a where clause that looks like this:
WHERE
CHARINDEX( LastName, '/') > 0 -- / exists
AND CHARINDEX( LastName, '/', CHARINDEX( LastName, '/') + 1) = 0 -- No second /s
I'll avoid discussing how much the design decision there makes me cringe... it's very denormalized.
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
October 4, 2012 at 6:21 pm
Here's another way:
WHERE LEN(LastName) - 1 = LEN(REPLACE(LastName, '/', ''))
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
October 5, 2012 at 3:16 pm
Thank you both for the help, dwain I've used your example for getting the column information. It works great however it returns rows that begin with a '/' too which isn't exactly what I want. Is there a way to query only the last names with at least one character (letter or number) before the '/'? For example, last names like 'e/johnson' but not names like '/johnson'.
October 5, 2012 at 4:40 pm
AND SUBSTRING(LastName,1,1)<>'/' ---??
October 5, 2012 at 8:07 pm
gravitysucks (10/5/2012)
AND SUBSTRING(LastName,1,1)<>'/' ---??
Yes or:
AND LEFT(LTRIM(LastName), 1) <> '/'
The LTRIM is in case there are blanks only leading up to the slash.
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
October 6, 2012 at 1:17 pm
CELKO (10/5/2012)
You are not just new to the forums, but have never read anything about RDBMS.
Backoff the new guy, Joe. You don't know if he created the denormalized data or not. Even if he did, that's not teaching and there's no need for that kind of comment.
What you have is an attempt at a variant record in several different 1950's threu 1970's file systems.
BWAA-HAAA!!! You always say stuff like that but aren't you still using a 1950s push-stack to convert Adjacency Lists to Nested Sets?
If you do nto care about being a good SQL programmer, there are several kludges for splitting this string into separate values.
Once again, you're totally out of line with such a comment. Good programmers will, in fact, use some of the "kludges" to normalize the data if they're allowed and to simply use the data if they're not. Heh... and it's not nearly as bad as the push-stack kludge. π
--Jeff Moden
Change is inevitable... Change for the better is not.
October 8, 2012 at 9:10 am
Thank you all for the samples, dwain.c I utilized your excerpt and it worked for me. I appreciate everyone's help!
October 8, 2012 at 10:26 am
SELECT lastname
FROM HR.Employees
WHERE
lastname LIKE '%[/]%' AND
lastname NOT LIKE '%[/]%[/]%'
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".
October 8, 2012 at 2:11 pm
ScottPletcher (10/8/2012)
SELECT lastname
FROM HR.Employees
WHERE
lastname LIKE '%[/]%' AND
lastname NOT LIKE '%[/]%[/]%'
Still have to add the line that removes / in the first character. I also believe you would want to remove any where / was the last character...
And Left(Ltrim(LastName), 1) <> '/'
And Right(Rtrim(LastName),1) <> '/'
I'm curious if this would not be a good option from an execution plan perspective? Are there better / faster ways of completing this?
[font="Arial"]βAny fool can know. The point is to understand.β
- Albert Einstein
"DOH!"
- Homer Simpson[/font]
October 8, 2012 at 2:47 pm
jarid.lawson (10/8/2012)
ScottPletcher (10/8/2012)
SELECT lastname
FROM HR.Employees
WHERE
lastname LIKE '%[/]%' AND
lastname NOT LIKE '%[/]%[/]%'
Still have to add the line that removes / in the first character. I also believe you would want to remove any where / was the last character...
And Left(Ltrim(LastName), 1) <> '/'
And Right(Rtrim(LastName),1) <> '/'
I'm curious if this would not be a good option from an execution plan perspective? Are there better / faster ways of completing this?
Oops, I didn't initially read down far enough to see the new requirement of not a leading /:
SELECT lastname
FROM HR.Employees
WHERE
lastname LIKE '[^/]%[/]%' AND
lastname NOT LIKE '[^/]%[/]%[/]%'
[/quote]
In theory this could potentially be faster with a covering index on lastname (probably likely, if you plan on running this query very often), whereas the queries using REPLACE(...) or any other function on the lastname column would require a full table scan.
That is, "lastname [NOT] like" is SARGable but "<function>(... lastname ...)" is not.
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".
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply