Django ORM if you already know SQL
If you are migrating to Django from another MVC framework, chances are you already know SQL.
In this post, I will be illustrating how to use Django ORM by drawing analogies to equivalent SQL statements. Connecting a new topic to your existing knowledge will help you learn to use the ORM faster.
Let us consider a simple base model for a person with attributes name, age, and gender.
To implement the above entity, we would model it as a table in SQL.
CREATE TABLE Person (
id int,
varchar(50),
name int NOT NULL,
age varchar(10),
gender );
The same table is modeled in Django as a class which inherits from the base Model class. The ORM creates the equivalent table under the hood.
class Person(models.Model):
= models.CharField(max_length=50, blank=True)
name = models.IntegerField()
age = models.CharField(max_length=10, blank=True) gender
The most used data types are:
SQL | Django |
---|---|
INT |
IntegerField() |
VARCHAR(n) |
CharField(max_length=n) |
TEXT |
TextField() |
FLOAT(n) |
FloatField() |
DATE |
DateField() |
TIME |
TimeField() |
DATETIME |
DateTimeField() |
The various queries we can use are:
## SELECT Statement
Fetch all rows
SQL:
SELECT *
FROM Person;
Django:
= Person.objects.all()
persons for person in persons:
print(person.name)
print(person.gender)
print(person.age)
Fetch specific columns
SQL:
SELECT name, age
FROM Person;
Django:
'name', 'age') Person.objects.only(
Fetch distinct rows
SQL:
SELECT DISTINCT name, age
FROM Person;
Django:
'name', 'age').distinct() Person.objects.values(
Fetch specific number of rows
SQL:
SELECT *
FROM Person
LIMIT 10;
Django:
all()[:10] Person.objects.
LIMIT AND OFFSET keywords
SQL:
SELECT *
FROM Person
5
OFFSET LIMIT 5;
Django:
all()[5:10] Person.objects.
WHERE Clause
Filter by single column
SQL:
SELECT *
FROM Person
WHERE id = 1;
Django:
filter(id=1) Person.objects.
Filter by comparison operators
SQL:
WHERE age > 18;
WHERE age >= 18;
WHERE age < 18;
WHERE age <= 18;
WHERE age != 18;
Django:
filter(age__gt=18)
Person.objects.filter(age__gte=18)
Person.objects.filter(age__lt=18)
Person.objects.filter(age__lte=18)
Person.objects.=18) Person.objects.exclude(age
BETWEEN Clause
SQL:
SELECT *
FROM Person
WHERE age BETWEEN 10 AND 20;
Django:
filter(age__range=(10, 20)) Person.objects.
LIKE operator
SQL:
WHERE name like '%A%';
WHERE name like binary '%A%';
WHERE name like 'A%';
WHERE name like binary 'A%';
WHERE name like '%A';
WHERE name like binary '%A';
Django:
filter(name__icontains='A')
Person.objects.filter(name__contains='A')
Person.objects.filter(name__istartswith='A')
Person.objects.filter(name__startswith='A')
Person.objects.filter(name__iendswith='A')
Person.objects.filter(name__endswith='A') Person.objects.
IN operator
SQL:
WHERE id in (1, 2);
Django:
filter(id__in=[1, 2]) Person.objects.
AND, OR and NOT Operators
SQL:
WHERE gender='male' AND age > 25;
Django:
filter(gender='male', age__gt=25) Person.objects.
SQL:
WHERE gender='male' OR age > 25;
Django:
from django.db.models import Q
filter(Q(gender='male') | Q(age__gt=25)) Person.objects.
SQL:
WHERE NOT gender='male';
Django:
='male') Person.objects.exclude(gender
NULL Values
SQL:
WHERE age is NULL;
WHERE age is NOT NULL;
Django:
filter(age__isnull=True)
Person.objects.filter(age__isnull=False)
Person.objects.
# Alternate approach
filter(age=None)
Person.objects.=None) Person.objects.exclude(age
ORDER BY Keyword
Ascending Order
SQL:
SELECT *
FROM Person
order by age;
Django:
'age') Person.objects.order_by(
Descending Order
SQL:
SELECT *
FROM Person
ORDER BY age DESC;
Django:
'-age') Person.objects.order_by(
INSERT INTO Statement
SQL:
INSERT INTO Person
VALUES ('Jack', '23', 'male');
Django:
='jack', age=23, gender='male) Person.objects.create(name
UPDATE Statement
Update single row
SQL:
UPDATE Person
SET age = 20
WHERE id = 1;
Django:
= Person.objects.get(id=1)
person = 20
person.age person.save()
Update multiple rows
SQL:
UPDATE Person
SET age = age * 1.5;
Django:
from django.db.models import F
=F('age')*1.5) Person.objects.update(age
DELETE Statement
Delete all rows
SQL:
DELETE FROM Person;
Django:
all().delete() Person.objects.
Delete specific rows
SQL:
DELETE FROM Person
WHERE age < 10;
Django:
filter(age__lt=10).delete() Person.objects.
Aggregation
MIN Function
SQL:
SELECT MIN(age)
FROM Person;
Django:
>>> from django.db.models import Min
>>> Person.objects.all().aggregate(Min('age'))
'age__min': 0} {
MAX Function
SQL:
SELECT MAX(age)
FROM Person;
Django:
>>> from django.db.models import Max
>>> Person.objects.all().aggregate(Max('age'))
'age__max': 100} {
AVG Function
SQL:
SELECT AVG(age)
FROM Person;
Django:
>>> from django.db.models import Avg
>>> Person.objects.all().aggregate(Avg('age'))
'age__avg': 50} {
SUM Function
SQL:
SELECT SUM(age)
FROM Person;
Django:
>>> from django.db.models import Sum
>>> Person.objects.all().aggregate(Sum('age'))
'age__sum': 5050} {
COUNT Function
SQL:
SELECT COUNT(*)
FROM Person;
Django:
Person.objects.count()
GROUP BY Statement
Count of Person by gender
SQL:
SELECT gender, COUNT(*) as count
FROM Person
GROUP BY gender;
Django:
'gender').annotate(count=Count('gender')) Person.objects.values(
HAVING Clause
Count of Person by gender if number of person is greater than 1
SQL:
SELECT gender, COUNT('gender') as count
FROM Person
GROUP BY gender
HAVING count > 1;
Django:
=Count('gender'))
Person.objects.annotate(count'gender', 'count')
.values(filter(count__gt=1) .
JOINS
Consider a foreign key relationship between books and publisher.
class Publisher(models.Model):
= models.CharField(max_length=100)
name
class Book(models.Model):
= models.ForeignKey(Publisher, on_delete=models.CASCADE) publisher
Fetch publisher name for a book
SQL:
SELECT name
FROM Book
LEFT JOIN Publisher
ON Book.publisher_id = Publisher.id
WHERE Book.id=1;
Django:
= Book.objects.select_related('publisher').get(id=1)
book book.publisher.name
Fetch books which have specific publisher
SQL:
SELECT *
FROM Book
WHERE Book.publisher_id = 1;
Django:
= Publisher.objects.prefetch_related('book_set').get(id=1)
publisher = publisher.book_set.all() books