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
 General SQL Server Forums
 New to SQL Server Programming
 How to get Top 10 within another field.
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

Sae12
Starting Member

5 Posts

Posted - 04/26/2013 :  03:48:23  Show Profile  Reply with Quote
Hi,

I am working on SQL 2005 and want to do a query to get data for top 6 'suppliers' based on the sum of 'orders' and then top 10 'sites' of each of the these top 6 suppliers again based on the sum of orders. I can do it as two seperate queries but is there a clever way of doing all in one.My table is called tbl_CFTr.

Many thanks in advance.

visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 04/26/2013 :  03:58:22  Show Profile  Reply with Quote
yep do something like

SELECT *
FROM (SELECT TOP 6 supplier --WITH TIES
      FROM tbl_CFTr
      GROUP BY supplier
      ORDER BY SUM(OrderID) DESC
     )t
CROSS APPLY (SELECT TOP 10 sitename --WITH TIES
             FROM tbl_CFTr
             WHERE supplier = t.supplier
             GROUP BY sitename
             ORDER BY SUM(orderid) DESC
             )s


uncomment WITH TIES if you want to return suppliers/sites with duplicate order count too

Also I've assumed column names so make sure you use actual column names as required

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs

Edited by - visakh16 on 04/26/2013 04:22:28
Go to Top of Page

Sae12
Starting Member

5 Posts

Posted - 04/26/2013 :  04:34:08  Show Profile  Reply with Quote
Thank you so much STAR.It's worked great. However, if I want to include the orders as well, it gives me an error.. How do I include Orders in the final result?

quote:
Originally posted by visakh16

yep do something like

SELECT *
FROM (SELECT TOP 6 supplier --WITH TIES
      FROM tbl_CFTr
      GROUP BY supplier
      ORDER BY SUM(OrderID) DESC
     )t
CROSS APPLY (SELECT TOP 10 sitename --WITH TIES
             FROM tbl_CFTr
             WHERE supplier = t.supplier
             GROUP BY sitename
             ORDER BY SUM(orderid) DESC
             )s


uncomment WITH TIES if you want to return suppliers/sites with duplicate order count too

Also I've assumed column names so make sure you use actual column names as required

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs


Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 04/26/2013 :  04:43:56  Show Profile  Reply with Quote
Order details are in which table? and how is it related to the above table?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

Sae12
Starting Member

5 Posts

Posted - 04/26/2013 :  05:10:38  Show Profile  Reply with Quote
It's the OrderId in tbl_CFTr. I would like to include that in my final result.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 04/26/2013 :  05:13:53  Show Profile  Reply with Quote
but you've counting orders right. then how can you return individually order details with it?

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

Sae12
Starting Member

5 Posts

Posted - 04/26/2013 :  05:35:38  Show Profile  Reply with Quote
Sorry - I think I wasn't very clear. The OrderId that you have used initially is basically number of 'orders' placed by a supplier/site.
If I run your query as it is, I get 2 cols (Supplier and Site) and 60 rows (top 6 supplier * top 10 supplier sites) which is what I want. All I want is a third col 'Orders' which is SUM of orders for that supplier and site.
My apologies if still not clear.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 04/26/2013 :  05:50:17  Show Profile  Reply with Quote

SELECT *
FROM (SELECT TOP 6 supplier,SUM(OrderID) AS supplierordertotalcount --WITH TIES
      FROM tbl_CFTr
      GROUP BY supplier
      ORDER BY SUM(OrderID) DESC
     )t
CROSS APPLY (SELECT TOP 10 sitename,SUM(OrderID) AS siteordercount --WITH TIES
             FROM tbl_CFTr
             WHERE supplier = t.supplier
             GROUP BY sitename
             ORDER BY SUM(orderid) DESC
             )s


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

Sae12
Starting Member

5 Posts

Posted - 04/26/2013 :  06:02:09  Show Profile  Reply with Quote
Thank you so much again Visakh16. This is what I exactly want :)
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 04/26/2013 :  06:02:41  Show Profile  Reply with Quote
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
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.11 seconds. Powered By: Snitz Forums 2000