February 19, 2009 at 7:32 am
hi everybody,
i have 3 tables
1. customer_master(customerid, customername)
2. language_master(languageid, languagename)
3. customer_language(customerid, languageid)
i will get a parameter like 'english, kannada, punjabi' to my stored procedure or query. how simple can I get all the customers who speak all the 3 languages.
Who is wise? He that learns from everyone. Who is powerful? He that governs his passions. Who is rich? He that is content. Who is that? Nobody.:)
February 19, 2009 at 9:21 am
There are a bunch of functions available in the Scripts area of the site. You do a search to track them down. Here's the one at the top of the list:http://www.sqlservercentral.com/scripts/Miscellaneous/31913/[/url]
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
February 19, 2009 at 9:42 am
Thanks for ur reply. is there any other better way to do this?
Who is wise? He that learns from everyone. Who is powerful? He that governs his passions. Who is rich? He that is content. Who is that? Nobody.:)
February 19, 2009 at 10:36 am
I know of four ways to do this, a function, a tally table, ad hoc queries or changing the data to XML. You have a function. This article [/url]is by Jeff Moden. He's the man where this is concerned. You can simply build a query so that you can insert your comma-delimited list into an IN clause, but that's going to cause recompiles and possibly bad performance. Converting to XML will work, but it's much more memory intensive and slower. I'd stick with the tally table (1st choice) or the function (2nd choice).
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
February 20, 2009 at 9:51 pm
Thanks for the kudo, Grant. 🙂
--Jeff Moden
Change is inevitable... Change for the better is not.
February 21, 2009 at 4:36 am
Credit where it's due.
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
February 21, 2009 at 5:30 am
Credit is due and all good, but that still does not answer the question....
SELECT m.customerid, m.customername
FROM dbo.customer_master m
inner join dbo.customer_language cl on m.customerid = cl.customerid
inner join dbo.language_master lm on cl.languageid = lm.languageid
where lm.languagename IN (Select languageName from dbo.JeffsFunction(@Languages)) -- Fetch the languages here with Jeff's code
--this is the not so obvious part that answer the question you are asking
GROUP BY m.customerid, m.customername
HAVING COUNT(*) = (SELECT COUNT(*) FROM dbo.JeffsFunction)
You need to know how many languages are in the parameter string (can be in a separate parameter to avoid calling the split function twice), then you need to count how many languages are matching per customer and make sure that those 2 numbers are equal... hence that customer speaks all required languages.
February 21, 2009 at 8:18 am
Ninja's_RGR'us (2/21/2009)
Credit is due and all good, but that still does not answer the question....
True enough... we were waiting on some test data so we could show some tested code.
[font="Arial Black"]Naveen[/font], take a look at the article in my signature below to get better answers quicker.
--Jeff Moden
Change is inevitable... Change for the better is not.
February 21, 2009 at 9:08 am
Hi
Thanks for all the replies and suggestions. here is the query to get the required reuslt
SELECT c.customer
FROM #customer_master c
INNER JOIN
(
SELECT cl.customerid,COUNT(DISTINCT l.languagename) AS langcnt
FROM #customer_language cl
INNER JOIN #language_master l
ON l.languageid=cl.languageid
INNER JOIN (SELECT ltrim(f.Val) as val FROM dbo.split(@param,',')f)t
ON t.Val=l.languagename
GROUP BY cl.customerid
)tmp
ON tmp.customerid=c.customerid
WHERE langcnt=(SELECT COUNT(DISTINCT f1.Val) FROM dbo.split(@param,',')f1)
parametere will be like
@param = 'hindi, telugu'
Who is wise? He that learns from everyone. Who is powerful? He that governs his passions. Who is rich? He that is content. Who is that? Nobody.:)
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply