Ask the Expert

Totals by yearly quarters

I have a table that contains sales data with the following columns that are important to me: Customer#, SalesDate, SalesAmount. I would like to be able to total the SalesAmount into yearly quarters (i.e. Q1, Q2,...), for each customer. Is it possible to do this in one query? I'm using a Progress database, so any functions available in Access/SQLServer/Oracle are not available to me, I'm afraid. Thank you!

    Requires Free Membership to View

Allow me to offer my condolences. A quick Web search turns up two references: Progress SQL-89 Guide and Reference and Progress SQL-92 Guide and Reference. Sure enough, the SQL-92 version supports a substantial list of scalar functions including DAYOFYEAR, so you could write:

select Customer#
     , case dayofyear(SalesDate)
          when <  92 then 1
          when < 183 then 2
          when < 274 then 3
          else 4
       end           as Quarter    
     , sum(SalesAmount)
  from SalesData
group
    by Customer#
     , case dayofyear(SalesDate)
          when <  92 then 1
          when < 183 then 2
          when < 274 then 3
          else 4
       end 

However, if you are using the SQL-89 version, it looks like you need another way to find the day number. There is no indication that you could do something even as simple as adding an integer to a date (see The integers table for an example of generating a series of dates). The only obvious solution that requires no date calculations or functions is a calendar table which will allow you to associate every date with its quarter:

create table Calendar
     ( CalDate  date not null
     , Q    smallint not null   
     ).
insert into Calendar values ('01/01/04',1).     
insert into Calendar values ('01/02/04',1).     
insert into Calendar values ('01/03/04',1).     
insert into Calendar values ('01/04/04',1).     
...
insert into Calendar values ('12/29/04',4).     
insert into Calendar values ('12/30/04',4).     
insert into Calendar values ('12/31/04',4). 

Two quirks that I spotted in the SQL-89 manual: each statement must end in a period, and date strings must be specified as mm/dd/yy. Now you can say:

select Customer#
     , Q  
     , sum(SalesAmount)
  from Calendar
     , SalesData
 where CalDate = SalesDate   
group
    by Customer#
     , Q.

One final note: in the first solution above, the assumption is that the first 91 days of the calendar year are in Q1, the second 91 in Q2, and the last 92 or 93, as the case may be, are in Q4. Realistically, this just doesn't happen.

In most organizations that use quarters or similar types of fiscal period, everything is measured in whole weeks. In 2004, January 1 through 3 would most likely be part of Q4 of 2003, since there are more 2003 days in that week than 2004 days. Likewise, January 1st of 2005 would likely be part of Q4 in 2004. When your quarters are actually fiscal quarters, you really do need to use a calendar table, and it should look like this:

create table Calendar
     ( CalDate  date not null
     , FY   smallint not null   
     , FQ   smallint not null   
     ).
insert into Calendar values ('01/01/04',2003,4).     
insert into Calendar values ('01/02/04',2003,4).     
insert into Calendar values ('01/03/04',2003,4). 
insert into Calendar values ('01/04/04',2004,1).
...
insert into Calendar values ('12/29/04',2004,4).     
insert into Calendar values ('12/30/04',2004,4).     
insert into Calendar values ('12/31/04',2004,4). 
insert into Calendar values ('01/01/05',2004,4).  
insert into Calendar values ('01/02/05',2005,1).

Now just join on the date and group by the fiscal year and fiscal quarter.


This was first published in February 2004

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to: