Ask the Expert

Crosstab totals per quarter

How can I create a crosstab of labor hours worked by quarter for each employee? The labor dates are listed individually for each employee. How do I code this per "quarter"?

    Requires Free Membership to View

This problem has two components: grouping totals by quarter, and creating crosstab output.

Grouping totals by quarter is easy if your database system has a date function that can extract the quarter from a date. For example, in Microsoft Access, you can write

select employeeno
     , datepart("q",labordate) as quarter
     , sum(laborhours)         as sumhours
  from yourtable
group
    by employeeno
     , datepart("q",labordate)

What if your database has no "quarter" date function? Then you could use the database's MONTH function. In order to group by quarter, we note that the quarters are given by months 1-3, 4-6, 7-9, and 10-12:

select employeeno
     , case 
        when month(labordate) between 1 and 3 
         then 1
        when month(labordate) between 4 and 6 
         then 2
        when month(labordate) between 7 and 9 
         then 3
         else 4
       end             as quarter
     , sum(laborhours) as sumhours
  from yourtable
group
    by employeeno
     , quarter

Instead of the CASE construct, you could also do arithmetic on the month number to come up with the quarter:

select employeeno
     , cast( (month(labordate)+2) / 3 
            as integer )
                       as quarter
     , ...

The only hitch with the two above approaches is that some databases may not let you use the column alias "quarter" in the GROUP BY clause, so you would have to repeat the CASE construct or the CAST function in the GROUP BY clause.

Finally, a solution using an integers table is:

select employeeno
     , i               as quarter
     , sum(laborhours) as sumhours
  from integers
inner
  join yourtable
    on i * 3 = month(labordate)
 where i between 1 and 4
group
    by employeeno
     , i

The integers table is used in a similar way in Grouping output by week (24 October 2002).

But what about producing the output in a crosstab? Well, the best approach here is to use a reporting language. Microsoft Access has this built in, and it works really well.

However, if you do want to do it just with SQL, it would look like this:

select employeeno
     , sum (
        case 
          when month(labordate) between 1 and 3 
          then laborhours
          else 0
        end )  as quarter1hours
     , sum (
        case 
          when month(labordate) between 4 and 6
          then laborhours
          else 0
        end )  as quarter2hours
     , sum (
        case 
          when month(labordate) between 7 and 9
          then laborhours
          else 0
        end )  as quarter3hours
     , sum (
        case 
          when month(labordate) between 10 and 12
          then laborhours
          else 0
        end )  as quarter4hours
  from yourtable
group
    by employeeno

This was first published in November 2002

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: