× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



Thanks all for the suggestions. I'll give them a try. Pushing my SQL
knowledge right to the edge on this one. TIME TO LEARN!

--
Mike Wills
http://mikewills.me
Ph: 507-933-0880


On Sat, Feb 2, 2019 at 4:40 AM Birgitta Hauser <Hauser@xxxxxxxxxxxxxxx>
wrote:

If I understand correctly you need the first 100 rows with the highest
usage
for each customer and due_date.
If so, you need both a CTE (or nested Sub-Select) and one of the
OLAP-Ranking Functions.

With x as (Select Customer, Due_Date, USAGE, row_Number() Over (Partition
By
Customer, Due_Date Order By Usage Desc) Counter
From BillHist)
Select Customer, Due_Date, Usage
From x
Where Counter <= 100;

In the CTE you need to add the OLAP Function, for building a counter for
each customer and Due_Date and which restarts for each customer and
Due_Date.
Row_Number() Over() is only a counter.
Dense_Rank() Over() and Dense_Rank() Over() are ranks, i.e. the same usage
gets the same rank.
Oder By in the Over clause handles the sort sequence of the numbering. In
this example it uses USAGE descending.
Partition By in the Over clause handles the level break. In this example
Customer, Due_Date.

In the final SELECT all rows with a counter <= 100 are returned.
An OLAP function cannot specified in the WHERE conditions, that's why you
need the CTE (alternatively you could also use a nested Sub-Select)


Mit freundlichen Grüßen / Best regards

Birgitta Hauser

"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"
„Train people well enough so they can leave, treat them well enough so they
don't want to.“ (Richard Branson)


-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of Mike
Wills
Sent: Freitag, 1. Februar 2019 22:29
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxx>
Subject: Select Top 100 in a Group By

Hey everyone, it's been a while.

I am hoping for a shortcut on this, but I'm guessing there isn't. We have a
request to pull a years worth of top usage data by due date.

So we have utility bills by customer and due date. We want to pull all
customers that have the top usage by each billing cycle. I know how to pull
that for all records, is there a shortcut way to pull the top x by a group
by?

I am thinking like
SELECT CUSTOMER, DUE_DATE, TOP100(USAGE) FROM BILLHIST GROUP BY CUSTOMER,
DUE_DATE

If there isn't, I guess I'll have to get creative. I'd build a program, but
we only need it a couple times until May when this software will be done
and
we'll be on a .NET platform.

--
Mike Wills
http://mikewills.me
Ph: 507-933-0880
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To subscribe,
unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxx for any subscription related
questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link:
https://amazon.midrange.com

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives
at https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxx for any subscription related
questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link: https://amazon.midrange.com


As an Amazon Associate we earn from qualifying purchases.

This thread ...

Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.