Returns number of rows matching the given criteria (i.e. applied with filter and exclude).
If distinct is True (the default), this will return the number of primary rows selected. If False,
the count will be the total number of rows returned
(including extra rows for one-to-many or many-to-many left select_related table joins).
False is the legacy (buggy) behavior for workflows that depend on it.
# returns a boolean value if given row existshas_sample=awaitBook.objects.filter(title='Sample').exists()
sum
sum(columns) -> Any
Returns sum value of columns for rows matching the given criteria (applied with filter and exclude if set before).
You can pass one or many column names including related columns.
As of now each column passed is aggregated separately (so sum(col1+col2) is not possible,
you can have sum(col1, col2) and later add 2 returned sums in python)
You cannot sum non numeric columns.
If you aggregate on one column, the single value is directly returned as a result
If you aggregate on multiple columns a dictionary with column: result pairs is returned
author=awaitAuthor(name="Author 1").save()awaitBook(title="Book 1",year=1920,ranking=3,author=author).save()awaitBook(title="Book 2",year=1930,ranking=1,author=author).save()awaitBook(title="Book 3",year=1923,ranking=5,author=author).save()assertawaitBook.objects.sum("year")==5773result=awaitBook.objects.sum(["year","ranking"])assertresult==dict(year=5773,ranking=9)try:# cannot sum string columnawaitBook.objects.sum("title")exceptormar.QueryDefinitionError:passassertawaitAuthor.objects.select_related("books").sum("books__year")==5773result=awaitAuthor.objects.select_related("books").sum(["books__year","books__ranking"])assertresult==dict(books__year=5773,books__ranking=9)assert(awaitAuthor.objects.select_related("books").filter(books__year__lt=1925).sum("books__year")==3843)
avg
avg(columns) -> Any
Returns avg value of columns for rows matching the given criteria (applied with filter and exclude if set before).
You can pass one or many column names including related columns.
As of now each column passed is aggregated separately (so sum(col1+col2) is not possible,
you can have sum(col1, col2) and later add 2 returned sums in python)
You cannot avg non numeric columns.
If you aggregate on one column, the single value is directly returned as a result
If you aggregate on multiple columns a dictionary with column: result pairs is returned
Returns min value of columns for rows matching the given criteria (applied with filter and exclude if set before).
You can pass one or many column names including related columns.
As of now each column passed is aggregated separately (so sum(col1+col2) is not possible,
you can have sum(col1, col2) and later add 2 returned sums in python)
If you aggregate on one column, the single value is directly returned as a result
If you aggregate on multiple columns a dictionary with column: result pairs is returned
Returns max value of columns for rows matching the given criteria (applied with filter and exclude if set before).
Returns min value of columns for rows matching the given criteria (applied with filter and exclude if set before).
You can pass one or many column names including related columns.
As of now each column passed is aggregated separately (so sum(col1+col2) is not possible,
you can have sum(col1, col2) and later add 2 returned sums in python)
If you aggregate on one column, the single value is directly returned as a result
If you aggregate on multiple columns a dictionary with column: result pairs is returned