sqlschool.gr logo

articles

Articles of SQLschool.gr Team

Select Top N rows from multiple groups

Antonios Chatzipavlis
Thursday 24 July 2014

Κατά ένα περίεργο τρόπο τις τελευταίες δύο εβδομάδες έχω γίνει αποδέκτης του συγκεκριμένου ερωτήματος από αρκετούς που επισκέπτονται το sqlschool.gr και για αυτό αποφάσισα να το κάνω post ώστε να υπάρχει και εδώ.

Η απάντηση στο ερώτημα δίνεται με τη χρήση window functions και συγκεκριμένα της ROW_NUMBER και επειδή δεν μπορείς λόγο της λογικής εκτέλεσης του query να αναφερθείς απευθείας σε αυτή κάνουμε χρήση ενός Common Table Expression (CTE) στο οποίο βάζουμε ένα φίλτρο στο νούμερο αυτό με τον Ν αριθμό που θέλουμε

Ολοκληρωμένο το συγκεκριμένο ερώτημα είναι στο παρακάτω παράδειγμα το οποίο χρησιμοποιεί την βάση AdventureWorks2012. Αυτό παίζει και στο 2005, 2008, 2008R2 και φυσικά 2012 και 2014.

Καλό θα είναι για να καταλάβετε τι γίνεται να εκτελέσετε τμηματικά το παράδειγμα και να γνωρίζεται τι είναι window functions και CTE (ψάξτε στα BOL)


use AdventureWorks2012;
go

with R 
as
(
    select    
          c.Name as Category
        , p.Name as Product
        , sum(od.OrderQty) as QntTotal
        , ROW_NUMBER() over ( partition by c.Name 
                              order by sum(od.OrderQty) desc) as rn
    from Sales.SalesOrderDetail as od
        inner join  Production.Product as p on od.ProductID=p.ProductID
        inner join  Production.ProductSubcategory as s on p.ProductSubcategoryID = s.ProductCategoryID
        inner join    Production.ProductCategory as c on c.ProductCategoryID=s.ProductCategoryID
    group by  c.Name , p.Name 
)
select * from R
    where rn <=2
order by Category,rn;
go

/*antonch*/

Antonios Chatzipavlis

Antonios Chatzipavlis

Antonios is a Data Solutions Consultant and Trainer. He has been working in IT since 1988. In his career, he has worked as senior developer, IT Manager, Solutions Architect and IT Consultant. Since 1995 he has been devoted on new technologies and software development tools, mainly by Microsoft, either by training company staff and colleagues or assisting them in design, development and implementation as a consultant or chief developer. He has focused in Databases and Data Science since 1995. He specialized in Microsoft SQL Server since version 6.0 in areas like SQL Server Internals, Database Design and Development, Business Intelligence and in 2010 he has started working with Azure Data Platform, NoSQL databases, Big Data Technologies and Machine Learning. He is an active member of many IT communities in Greece, answering colleagues' questions and writing articles in his web site. He is the owner of SQLschool.gr which is a community portal with a lot of information about Microsoft SQL Server. He has been a Microsoft Certified Trainer (MCT) since 2000. Microsoft honored him as MVP on Data Platform due to his activities in SQL Server since 2010. He holds a large number of Microsoft Certifications and Microsoft SQL Server Certifications since version 6.5.

Episode

Task Flows in Microsoft Fabric

image

More Episodes...

Tip

What's New in SQL Server 2022 - Episodes

More Tips...

Become a member

If you want to receive updates from us become a member to our community.

Connect

Explore

Learn


sqlschool.gr © 2010-2025 All rights reserved

This site uses cookies for operational and analytics purposes only. By continuing to browse this site, you agree to their use.