This week we had a hackathon to develop a better internal dashboard page that shows things like records added to the system over time. Not having generated many reports in Django, we had to learn how to get the Django ORM to group records by day. It's a little bit of a weak spot in the still relatively new aggregation feature, so it wasn't as easy as we expected.

The first pass got the job done, but was pretty slow.

import datetime
import itertools
last_14_days = datetime.datetime.today() - datetime.timedelta(14)
jobs = Job.objects.filter(date_added__gte=last_14_days)
grouped = itertools.groupby(jobs, lambda record: record.date_added.strftime("%Y-%m-%d"))
jobs_by_day = [(day, len(list(jobs_this_day))) for day, jobs_this_day in grouped]
#[('2012-02-22', 1), ('2012-02-21', 1503), ('2012-02-20', 1351), ('2012-02-19', 200), ('2012-02-18', 157), ('2012-02-17', 1423), ('2012-02-16', 1665), ('2012-02-15', 1774), ('2012-02-14', 1533), ('2012-02-13', 1635), ('2012-02-12', 170), ('2012-02-11', 147), ('2012-02-10', 958)]

That works, but it's a little slow if you have hundreds of thousands of records in the dataset. The slowness is partially due to the ORM grabbing every field in the Job record, even though you only need date_added. Here is an optimization, assuming all you need are counts:

jobs = Job.objects.filter(date_added__gte=last_14_days).values("date_added")
grouped = itertools.groupby(jobs, lambda record: record.get("date_added").strftime("%Y-%m-%d"))
jobs_by_day = [(day, len(list(jobs_this_day))) for day, jobs_this_day in grouped]

Even that is a lot slower than it needs to be. For the best performance, you want the grouping to happen in your database. In raw SQL, you would do something like:

-- this syntax is Postgres specific
  select date_trunc('day', date_added),
         count(*)
    from website_job
   where date_added > now() - interval '14 days'
group by date_trunc('day', date_added)
order by date_trunc('day', date_added)

/*
2012-02-10 00:00:00:000;916
2012-02-11 00:00:00:000;147
2012-02-12 00:00:00:000;170
2012-02-13 00:00:00:000;1635
2012-02-14 00:00:00:000;1533
2012-02-15 00:00:00:000;1774
2012-02-16 00:00:00:000;1665
2012-02-17 00:00:00:000;1423
2012-02-18 00:00:00:000;157
2012-02-19 00:00:00:000;200
2012-02-20 00:00:00:000;1351
2012-02-21 00:00:00:000;1503
2012-02-22 00:00:00:000;1
*/

You can have the Django ORM pass this raw SQL for a group by as well, as long as you don't mind that you're violating the database-independence barrier.

from django.db.models.aggregates import Count
jobs = Job.objects.filter(date_added__gte=last_14_days).extra({"day": "date_trunc('day', date_added)"}).values("day").order_by().annotate(count=Count("id"))
#[{'count': 1423, 'day': datetime.datetime(2012, 2, 17, 0, 0)}, {'count': 147, 'day': datetime.datetime(2012, 2, 11, 0, 0)}, {'count': 1351, 'day': datetime.datetime(2012, 2, 20, 0, 0)}, {'count': 1665, 'day': datetime.datetime(2012, 2, 16, 0, 0)}, {'count': 1774, 'day': datetime.datetime(2012, 2, 15, 0, 0)}, {'count': 200, 'day': datetime.datetime(2012, 2, 19, 0, 0)}, {'count': 157, 'day': datetime.datetime(2012, 2, 18, 0, 0)}, {'count': 1, 'day': datetime.datetime(2012, 2, 22, 0, 0)}, {'count': 958, 'day': datetime.datetime(2012, 2, 10, 0, 0)}, {'count': 1503, 'day': datetime.datetime(2012, 2, 21, 0, 0)}, {'count': 1635, 'day': datetime.datetime(2012, 2, 13, 0, 0)}, {'count': 1533, 'day': datetime.datetime(2012, 2, 14, 0, 0)}, {'count': 170, 'day': datetime.datetime(2012, 2, 12, 0, 0)}]

There is some trickiness here. We're defining a new column on each result called "day", which is calculated with the date_trunc() method by Postgres. Then we're using the standard values/annotate functionality in the Django ORM aggregation framework. Notice, however, that we must clear the default ordering with an explicit order_by() in between, otherwise the grouping will not work.

Another solution would be to denormalize day into its own field in your model, and just use the vanilla aggregation syntax. Hopefully these kinds of aggregations will get easier in future versions of Django.