#31377 closed Bug (fixed)
Django 3.0: "GROUP BY" clauses error with tricky field annotation
Reported by: | Holovashchenko Vadym | Owned by: | Hasan Ramezani |
---|---|---|---|
Component: | Database layer (models, ORM) | Version: | 3.0 |
Severity: | Release blocker | Keywords: | group by, postgres, annotate |
Cc: | Triage Stage: | Ready for checkin | |
Has patch: | yes | Needs documentation: | no |
Needs tests: | no | Patch needs improvement: | no |
Easy pickings: | no | UI/UX: | no |
Description
Let's pretend that we have next model structure with next model's relations:
class A(models.Model): bs = models.ManyToManyField('B', related_name="a", through="AB") class B(models.Model): pass class AB(models.Model): a = models.ForeignKey(A, on_delete=models.CASCADE, related_name="ab_a") b = models.ForeignKey(B, on_delete=models.CASCADE, related_name="ab_b") status = models.IntegerField() class C(models.Model): a = models.ForeignKey( A, null=True, blank=True, on_delete=models.SET_NULL, related_name="c", verbose_name=_("a") ) status = models.IntegerField()
Let's try to evaluate next query
ab_query = AB.objects.filter(a=OuterRef("pk"), b=1) filter_conditions = Q(pk=1) | Q(ab_a__b=1) query = A.objects.\ filter(filter_conditions).\ annotate( status=Subquery(ab_query.values("status")), c_count=Count("c"), ) answer = query.values("status").annotate(total_count=Count("status")) print(answer.query) print(answer)
On Django 3.0.4 we have an error
django.db.utils.ProgrammingError: column reference "status" is ambiguous
and query is next:
SELECT (SELECT U0."status" FROM "test_app_ab" U0 WHERE (U0."a_id" = "test_app_a"."id" AND U0."b_id" = 1)) AS "status", COUNT((SELECT U0."status" FROM "test_app_ab" U0 WHERE (U0."a_id" = "test_app_a"."id" AND U0."b_id" = 1))) AS "total_count" FROM "test_app_a" LEFT OUTER JOIN "test_app_ab" ON ("test_app_a"."id" = "test_app_ab"."a_id") LEFT OUTER JOIN "test_app_c" ON ("test_app_a"."id" = "test_app_c"."a_id") WHERE ("test_app_a"."id" = 1 OR "test_app_ab"."b_id" = 1) GROUP BY "status"
However, Django 2.2.11 processed this query properly with the next query:
SELECT (SELECT U0."status" FROM "test_app_ab" U0 WHERE (U0."a_id" = ("test_app_a"."id") AND U0."b_id" = 1)) AS "status", COUNT((SELECT U0."status" FROM "test_app_ab" U0 WHERE (U0."a_id" = ("test_app_a"."id") AND U0."b_id" = 1))) AS "total_count" FROM "test_app_a" LEFT OUTER JOIN "test_app_ab" ON ("test_app_a"."id" = "test_app_ab"."a_id") LEFT OUTER JOIN "test_app_c" ON ("test_app_a"."id" = "test_app_c"."a_id") WHERE ("test_app_a"."id" = 1 OR "test_app_ab"."b_id" = 1) GROUP BY (SELECT U0."status" FROM "test_app_ab" U0 WHERE (U0."a_id" = ("test_app_a"."id") AND U0."b_id" = 1))
so, the difference in "GROUP BY" clauses
(as DB provider uses "django.db.backends.postgresql", postgresql 11)
Change History (9)
comment:1 by , 5 years ago
Severity: | Normal → Release blocker |
---|---|
Triage Stage: | Unreviewed → Accepted |
comment:2 by , 5 years ago
Owner: | changed from | to
---|---|
Status: | new → assigned |
@Simon I think we have the check for collision in annotation alias and model fields .
How can we find the involved tables columns?
Thanks
comment:3 by , 5 years ago
Hasan this is another kind of collision, these fields are not selected and part of join tables so they won't be part of names
.
We can't change the behavior at the annotate()
level as it would be backward incompatible and require extra checks every time an additional table is joined.
What needs to be adjust is sql.Query.set_group_by
to set alias=None
if alias is not None and alias in {... set of all column names of tables in alias_map ...}
.
comment:4 by , 5 years ago
Has patch: | set |
---|
Simon, I've created a patch to fix this problem.
I think the collision, in this case, is between C.status
and the status annotation. if we remove c_count=Count("c")
from the query we won't have the error. So, I created a Book1
test model in my patch to simulate the query.
comment:6 by , 5 years ago
Triage Stage: | Accepted → Ready for checkin |
---|
This is due to a collision of
AB.status
and thestatus
annotation.The easiest way to solve this issue is to disable group by alias when a collision is detected with involved table columns. This can be easily worked around by avoiding to use an annotation name that conflicts with involved table column names.