Fixed #28574 -- Added QuerySet.explain().
This commit is contained in:
parent
df90e462d9
commit
c1c163b427
|
@ -250,9 +250,21 @@ class BaseDatabaseFeatures:
|
||||||
# Convert CharField results from bytes to str in database functions.
|
# Convert CharField results from bytes to str in database functions.
|
||||||
db_functions_convert_bytes_to_str = False
|
db_functions_convert_bytes_to_str = False
|
||||||
|
|
||||||
|
# What formats does the backend EXPLAIN syntax support?
|
||||||
|
supported_explain_formats = set()
|
||||||
|
|
||||||
|
# Does DatabaseOperations.explain_query_prefix() raise ValueError if
|
||||||
|
# unknown kwargs are passed to QuerySet.explain()?
|
||||||
|
validates_explain_options = True
|
||||||
|
|
||||||
def __init__(self, connection):
|
def __init__(self, connection):
|
||||||
self.connection = connection
|
self.connection = connection
|
||||||
|
|
||||||
|
@cached_property
|
||||||
|
def supports_explaining_query_execution(self):
|
||||||
|
"""Does this backend support explaining query execution?"""
|
||||||
|
return self.connection.ops.explain_prefix is not None
|
||||||
|
|
||||||
@cached_property
|
@cached_property
|
||||||
def supports_transactions(self):
|
def supports_transactions(self):
|
||||||
"""Confirm support for transactions."""
|
"""Confirm support for transactions."""
|
||||||
|
|
|
@ -45,6 +45,9 @@ class BaseDatabaseOperations:
|
||||||
UNBOUNDED_FOLLOWING = 'UNBOUNDED ' + FOLLOWING
|
UNBOUNDED_FOLLOWING = 'UNBOUNDED ' + FOLLOWING
|
||||||
CURRENT_ROW = 'CURRENT ROW'
|
CURRENT_ROW = 'CURRENT ROW'
|
||||||
|
|
||||||
|
# Prefix for EXPLAIN queries, or None EXPLAIN isn't supported.
|
||||||
|
explain_prefix = None
|
||||||
|
|
||||||
def __init__(self, connection):
|
def __init__(self, connection):
|
||||||
self.connection = connection
|
self.connection = connection
|
||||||
self._cache = None
|
self._cache = None
|
||||||
|
@ -652,3 +655,18 @@ class BaseDatabaseOperations:
|
||||||
|
|
||||||
def window_frame_range_start_end(self, start=None, end=None):
|
def window_frame_range_start_end(self, start=None, end=None):
|
||||||
return self.window_frame_rows_start_end(start, end)
|
return self.window_frame_rows_start_end(start, end)
|
||||||
|
|
||||||
|
def explain_query_prefix(self, format=None, **options):
|
||||||
|
if not self.connection.features.supports_explaining_query_execution:
|
||||||
|
raise NotSupportedError('This backend does not support explaining query execution.')
|
||||||
|
if format:
|
||||||
|
supported_formats = self.connection.features.supported_explain_formats
|
||||||
|
normalized_format = format.upper()
|
||||||
|
if normalized_format not in supported_formats:
|
||||||
|
msg = '%s is not a recognized format.' % normalized_format
|
||||||
|
if supported_formats:
|
||||||
|
msg += ' Allowed formats: %s' % ', '.join(sorted(supported_formats))
|
||||||
|
raise ValueError(msg)
|
||||||
|
if options:
|
||||||
|
raise ValueError('Unknown options: %s' % ', '.join(sorted(options.keys())))
|
||||||
|
return self.explain_prefix
|
||||||
|
|
|
@ -49,6 +49,8 @@ class DatabaseFeatures(BaseDatabaseFeatures):
|
||||||
END;
|
END;
|
||||||
"""
|
"""
|
||||||
db_functions_convert_bytes_to_str = True
|
db_functions_convert_bytes_to_str = True
|
||||||
|
# Alias MySQL's TRADITIONAL to TEXT for consistency with other backends.
|
||||||
|
supported_explain_formats = {'JSON', 'TEXT', 'TRADITIONAL'}
|
||||||
|
|
||||||
@cached_property
|
@cached_property
|
||||||
def _mysql_storage_engine(self):
|
def _mysql_storage_engine(self):
|
||||||
|
@ -81,6 +83,11 @@ class DatabaseFeatures(BaseDatabaseFeatures):
|
||||||
def supports_over_clause(self):
|
def supports_over_clause(self):
|
||||||
return self.connection.mysql_version >= (8, 0, 2)
|
return self.connection.mysql_version >= (8, 0, 2)
|
||||||
|
|
||||||
|
@cached_property
|
||||||
|
def needs_explain_extended(self):
|
||||||
|
# EXTENDED is deprecated (and not required) in 5.7 and removed in 8.0.
|
||||||
|
return self.connection.mysql_version < (5, 7)
|
||||||
|
|
||||||
@cached_property
|
@cached_property
|
||||||
def supports_transactions(self):
|
def supports_transactions(self):
|
||||||
"""
|
"""
|
||||||
|
|
|
@ -26,6 +26,7 @@ class DatabaseOperations(BaseDatabaseOperations):
|
||||||
'PositiveSmallIntegerField': 'unsigned integer',
|
'PositiveSmallIntegerField': 'unsigned integer',
|
||||||
}
|
}
|
||||||
cast_char_field_without_max_length = 'char'
|
cast_char_field_without_max_length = 'char'
|
||||||
|
explain_prefix = 'EXPLAIN'
|
||||||
|
|
||||||
def date_extract_sql(self, lookup_type, field_name):
|
def date_extract_sql(self, lookup_type, field_name):
|
||||||
# http://dev.mysql.com/doc/mysql/en/date-and-time-functions.html
|
# http://dev.mysql.com/doc/mysql/en/date-and-time-functions.html
|
||||||
|
@ -269,3 +270,15 @@ class DatabaseOperations(BaseDatabaseOperations):
|
||||||
) % {'lhs': lhs_sql, 'rhs': rhs_sql}, lhs_params * 2 + rhs_params * 2
|
) % {'lhs': lhs_sql, 'rhs': rhs_sql}, lhs_params * 2 + rhs_params * 2
|
||||||
else:
|
else:
|
||||||
return "TIMESTAMPDIFF(MICROSECOND, %s, %s)" % (rhs_sql, lhs_sql), rhs_params + lhs_params
|
return "TIMESTAMPDIFF(MICROSECOND, %s, %s)" % (rhs_sql, lhs_sql), rhs_params + lhs_params
|
||||||
|
|
||||||
|
def explain_query_prefix(self, format=None, **options):
|
||||||
|
# Alias MySQL's TRADITIONAL to TEXT for consistency with other backends.
|
||||||
|
if format and format.upper() == 'TEXT':
|
||||||
|
format = 'TRADITIONAL'
|
||||||
|
prefix = super().explain_query_prefix(format, **options)
|
||||||
|
if format:
|
||||||
|
prefix += ' FORMAT=%s' % format
|
||||||
|
if self.connection.features.needs_explain_extended and format is None:
|
||||||
|
# EXTENDED and FORMAT are mutually exclusive options.
|
||||||
|
prefix += ' EXTENDED'
|
||||||
|
return prefix
|
||||||
|
|
|
@ -50,6 +50,8 @@ class DatabaseFeatures(BaseDatabaseFeatures):
|
||||||
$$ LANGUAGE plpgsql;"""
|
$$ LANGUAGE plpgsql;"""
|
||||||
supports_over_clause = True
|
supports_over_clause = True
|
||||||
supports_aggregate_filter_clause = True
|
supports_aggregate_filter_clause = True
|
||||||
|
supported_explain_formats = {'JSON', 'TEXT', 'XML', 'YAML'}
|
||||||
|
validates_explain_options = False # A query will error on invalid options.
|
||||||
|
|
||||||
@cached_property
|
@cached_property
|
||||||
def is_postgresql_9_5(self):
|
def is_postgresql_9_5(self):
|
||||||
|
|
|
@ -7,6 +7,7 @@ from django.db.backends.base.operations import BaseDatabaseOperations
|
||||||
|
|
||||||
class DatabaseOperations(BaseDatabaseOperations):
|
class DatabaseOperations(BaseDatabaseOperations):
|
||||||
cast_char_field_without_max_length = 'varchar'
|
cast_char_field_without_max_length = 'varchar'
|
||||||
|
explain_prefix = 'EXPLAIN'
|
||||||
|
|
||||||
def unification_cast_sql(self, output_field):
|
def unification_cast_sql(self, output_field):
|
||||||
internal_type = output_field.get_internal_type()
|
internal_type = output_field.get_internal_type()
|
||||||
|
@ -258,3 +259,17 @@ class DatabaseOperations(BaseDatabaseOperations):
|
||||||
'and FOLLOWING.'
|
'and FOLLOWING.'
|
||||||
)
|
)
|
||||||
return start_, end_
|
return start_, end_
|
||||||
|
|
||||||
|
def explain_query_prefix(self, format=None, **options):
|
||||||
|
prefix = super().explain_query_prefix(format)
|
||||||
|
extra = {}
|
||||||
|
if format:
|
||||||
|
extra['FORMAT'] = format
|
||||||
|
if options:
|
||||||
|
extra.update({
|
||||||
|
name.upper(): 'true' if value else 'false'
|
||||||
|
for name, value in options.items()
|
||||||
|
})
|
||||||
|
if extra:
|
||||||
|
prefix += ' (%s)' % ', '.join('%s %s' % i for i in extra.items())
|
||||||
|
return prefix
|
||||||
|
|
|
@ -19,6 +19,7 @@ class DatabaseOperations(BaseDatabaseOperations):
|
||||||
'DateField': 'TEXT',
|
'DateField': 'TEXT',
|
||||||
'DateTimeField': 'TEXT',
|
'DateTimeField': 'TEXT',
|
||||||
}
|
}
|
||||||
|
explain_prefix = 'EXPLAIN QUERY PLAN'
|
||||||
|
|
||||||
def bulk_batch_size(self, fields, objs):
|
def bulk_batch_size(self, fields, objs):
|
||||||
"""
|
"""
|
||||||
|
|
|
@ -717,6 +717,9 @@ class QuerySet:
|
||||||
prefetch_related_objects(self._result_cache, *self._prefetch_related_lookups)
|
prefetch_related_objects(self._result_cache, *self._prefetch_related_lookups)
|
||||||
self._prefetch_done = True
|
self._prefetch_done = True
|
||||||
|
|
||||||
|
def explain(self, *, format=None, **options):
|
||||||
|
return self.query.explain(using=self.db, format=format, **options)
|
||||||
|
|
||||||
##################################################
|
##################################################
|
||||||
# PUBLIC METHODS THAT RETURN A QUERYSET SUBCLASS #
|
# PUBLIC METHODS THAT RETURN A QUERYSET SUBCLASS #
|
||||||
##################################################
|
##################################################
|
||||||
|
|
|
@ -530,6 +530,12 @@ class SQLCompiler:
|
||||||
result.append('HAVING %s' % having)
|
result.append('HAVING %s' % having)
|
||||||
params.extend(h_params)
|
params.extend(h_params)
|
||||||
|
|
||||||
|
if self.query.explain_query:
|
||||||
|
result.insert(0, self.connection.ops.explain_query_prefix(
|
||||||
|
self.query.explain_format,
|
||||||
|
**self.query.explain_options
|
||||||
|
))
|
||||||
|
|
||||||
if order_by:
|
if order_by:
|
||||||
ordering = []
|
ordering = []
|
||||||
for _, (o_sql, o_params, _) in order_by:
|
for _, (o_sql, o_params, _) in order_by:
|
||||||
|
@ -1101,6 +1107,16 @@ class SQLCompiler:
|
||||||
sql, params = self.as_sql()
|
sql, params = self.as_sql()
|
||||||
return 'EXISTS (%s)' % sql, params
|
return 'EXISTS (%s)' % sql, params
|
||||||
|
|
||||||
|
def explain_query(self):
|
||||||
|
result = list(self.execute_sql())
|
||||||
|
# Some backends return 1 item tuples with strings, and others return
|
||||||
|
# tuples with integers and strings. Flatten them out into strings.
|
||||||
|
for row in result[0]:
|
||||||
|
if not isinstance(row, str):
|
||||||
|
yield ' '.join(str(c) for c in row)
|
||||||
|
else:
|
||||||
|
yield row
|
||||||
|
|
||||||
|
|
||||||
class SQLInsertCompiler(SQLCompiler):
|
class SQLInsertCompiler(SQLCompiler):
|
||||||
return_id = False
|
return_id = False
|
||||||
|
|
|
@ -223,6 +223,10 @@ class Query:
|
||||||
|
|
||||||
self._filtered_relations = {}
|
self._filtered_relations = {}
|
||||||
|
|
||||||
|
self.explain_query = False
|
||||||
|
self.explain_format = None
|
||||||
|
self.explain_options = {}
|
||||||
|
|
||||||
@property
|
@property
|
||||||
def extra(self):
|
def extra(self):
|
||||||
if self._extra is None:
|
if self._extra is None:
|
||||||
|
@ -511,6 +515,14 @@ class Query:
|
||||||
compiler = q.get_compiler(using=using)
|
compiler = q.get_compiler(using=using)
|
||||||
return compiler.has_results()
|
return compiler.has_results()
|
||||||
|
|
||||||
|
def explain(self, using, format=None, **options):
|
||||||
|
q = self.clone()
|
||||||
|
q.explain_query = True
|
||||||
|
q.explain_format = format
|
||||||
|
q.explain_options = options
|
||||||
|
compiler = q.get_compiler(using=using)
|
||||||
|
return '\n'.join(compiler.explain_query())
|
||||||
|
|
||||||
def combine(self, rhs, connector):
|
def combine(self, rhs, connector):
|
||||||
"""
|
"""
|
||||||
Merge the 'rhs' query into the current one (with any 'rhs' effects
|
Merge the 'rhs' query into the current one (with any 'rhs' effects
|
||||||
|
|
|
@ -2476,6 +2476,49 @@ Class method that returns an instance of :class:`~django.db.models.Manager`
|
||||||
with a copy of the ``QuerySet``’s methods. See
|
with a copy of the ``QuerySet``’s methods. See
|
||||||
:ref:`create-manager-with-queryset-methods` for more details.
|
:ref:`create-manager-with-queryset-methods` for more details.
|
||||||
|
|
||||||
|
``explain()``
|
||||||
|
~~~~~~~~~~~~~
|
||||||
|
|
||||||
|
.. versionadded:: 2.1
|
||||||
|
|
||||||
|
.. method:: explain(format=None, **options)
|
||||||
|
|
||||||
|
Returns a string of the ``QuerySet``’s execution plan, which details how the
|
||||||
|
database would execute the query, including any indexes or joins that would be
|
||||||
|
used. Knowing these details may help you improve the performance of slow
|
||||||
|
queries.
|
||||||
|
|
||||||
|
For example, when using PostgreSQL::
|
||||||
|
|
||||||
|
>>> print(Blog.objects.filter(title='My Blog').explain())
|
||||||
|
Seq Scan on blog (cost=0.00..35.50 rows=10 width=12)
|
||||||
|
Filter: (title = 'My Blog'::bpchar)
|
||||||
|
|
||||||
|
The output differs significantly between databases.
|
||||||
|
|
||||||
|
``explain()`` is supported by all built-in database backends except Oracle
|
||||||
|
because an implementation there isn't straightforward.
|
||||||
|
|
||||||
|
The ``format`` parameter changes the output format from the databases's default,
|
||||||
|
usually text-based. PostgreSQL supports ``'TEXT'``, ``'JSON'``, ``'YAML'``, and
|
||||||
|
``'XML'``. MySQL supports ``'TEXT'`` (also called ``'TRADITIONAL'``) and
|
||||||
|
``'JSON'``.
|
||||||
|
|
||||||
|
Some databases accept flags that can return more information about the query.
|
||||||
|
Pass these flags as keyword arguments. For example, when using PostgreSQL::
|
||||||
|
|
||||||
|
>>> print(Blog.objects.filter(title='My Blog').explain(verbose=True))
|
||||||
|
Seq Scan on public.blog (cost=0.00..35.50 rows=10 width=12) (actual time=0.004..0.004 rows=10 loops=1)
|
||||||
|
Output: id, title
|
||||||
|
Filter: (blog.title = 'My Blog'::bpchar)
|
||||||
|
Planning time: 0.064 ms
|
||||||
|
Execution time: 0.058 ms
|
||||||
|
|
||||||
|
On some databases, flags may cause the query to be executed which could have
|
||||||
|
adverse effects on your database. For example, PostgreSQL's ``ANALYZE`` flag
|
||||||
|
could result in changes to data if there are triggers or if a function is
|
||||||
|
called, even for a ``SELECT`` query.
|
||||||
|
|
||||||
.. _field-lookups:
|
.. _field-lookups:
|
||||||
|
|
||||||
``Field`` lookups
|
``Field`` lookups
|
||||||
|
|
|
@ -236,6 +236,9 @@ Models
|
||||||
encouraged instead of :class:`~django.db.models.NullBooleanField`, which will
|
encouraged instead of :class:`~django.db.models.NullBooleanField`, which will
|
||||||
likely be deprecated in the future.
|
likely be deprecated in the future.
|
||||||
|
|
||||||
|
* The new :meth:`.QuerySet.explain` method displays the database's execution
|
||||||
|
plan of a queryset's query.
|
||||||
|
|
||||||
Requests and Responses
|
Requests and Responses
|
||||||
~~~~~~~~~~~~~~~~~~~~~~
|
~~~~~~~~~~~~~~~~~~~~~~
|
||||||
|
|
||||||
|
|
|
@ -555,6 +555,7 @@ class ManagerTest(SimpleTestCase):
|
||||||
'only',
|
'only',
|
||||||
'using',
|
'using',
|
||||||
'exists',
|
'exists',
|
||||||
|
'explain',
|
||||||
'_insert',
|
'_insert',
|
||||||
'_update',
|
'_update',
|
||||||
'raw',
|
'raw',
|
||||||
|
|
|
@ -0,0 +1,99 @@
|
||||||
|
import unittest
|
||||||
|
|
||||||
|
from django.db import NotSupportedError, connection, transaction
|
||||||
|
from django.db.models import Count
|
||||||
|
from django.test import TestCase, skipIfDBFeature, skipUnlessDBFeature
|
||||||
|
from django.test.utils import CaptureQueriesContext
|
||||||
|
|
||||||
|
from .models import Tag
|
||||||
|
|
||||||
|
|
||||||
|
@skipUnlessDBFeature('supports_explaining_query_execution')
|
||||||
|
class ExplainTests(TestCase):
|
||||||
|
|
||||||
|
def test_basic(self):
|
||||||
|
querysets = [
|
||||||
|
Tag.objects.filter(name='test'),
|
||||||
|
Tag.objects.filter(name='test').select_related('parent'),
|
||||||
|
Tag.objects.filter(name='test').prefetch_related('children'),
|
||||||
|
Tag.objects.filter(name='test').annotate(Count('children')),
|
||||||
|
Tag.objects.filter(name='test').values_list('name'),
|
||||||
|
Tag.objects.order_by().union(Tag.objects.order_by().filter(name='test')),
|
||||||
|
Tag.objects.all().select_for_update().filter(name='test'),
|
||||||
|
]
|
||||||
|
supported_formats = connection.features.supported_explain_formats
|
||||||
|
all_formats = (None,) + tuple(supported_formats) + tuple(f.lower() for f in supported_formats)
|
||||||
|
for idx, queryset in enumerate(querysets):
|
||||||
|
for format in all_formats:
|
||||||
|
with self.subTest(format=format, queryset=idx):
|
||||||
|
if connection.vendor == 'mysql':
|
||||||
|
# This does a query and caches the result.
|
||||||
|
connection.features.needs_explain_extended
|
||||||
|
with self.assertNumQueries(1), CaptureQueriesContext(connection) as captured_queries:
|
||||||
|
result = queryset.explain(format=format)
|
||||||
|
self.assertTrue(captured_queries[0]['sql'].startswith(connection.ops.explain_prefix))
|
||||||
|
self.assertIsInstance(result, str)
|
||||||
|
self.assertTrue(result)
|
||||||
|
|
||||||
|
@skipUnlessDBFeature('validates_explain_options')
|
||||||
|
def test_unknown_options(self):
|
||||||
|
with self.assertRaisesMessage(ValueError, 'Unknown options: test, test2'):
|
||||||
|
Tag.objects.all().explain(test=1, test2=1)
|
||||||
|
|
||||||
|
def test_unknown_format(self):
|
||||||
|
msg = 'DOES NOT EXIST is not a recognized format.'
|
||||||
|
if connection.features.supported_explain_formats:
|
||||||
|
msg += ' Allowed formats: %s' % ', '.join(sorted(connection.features.supported_explain_formats))
|
||||||
|
with self.assertRaisesMessage(ValueError, msg):
|
||||||
|
Tag.objects.all().explain(format='does not exist')
|
||||||
|
|
||||||
|
@unittest.skipUnless(connection.vendor == 'postgresql', 'PostgreSQL specific')
|
||||||
|
def test_postgres_options(self):
|
||||||
|
qs = Tag.objects.filter(name='test')
|
||||||
|
test_options = [
|
||||||
|
{'COSTS': False, 'BUFFERS': True, 'ANALYZE': True},
|
||||||
|
{'costs': False, 'buffers': True, 'analyze': True},
|
||||||
|
{'verbose': True, 'timing': True, 'analyze': True},
|
||||||
|
{'verbose': False, 'timing': False, 'analyze': True},
|
||||||
|
]
|
||||||
|
if connection.pg_version >= 100000:
|
||||||
|
test_options.append({'summary': True})
|
||||||
|
for options in test_options:
|
||||||
|
with self.subTest(**options), transaction.atomic():
|
||||||
|
with CaptureQueriesContext(connection) as captured_queries:
|
||||||
|
qs.explain(format='text', **options)
|
||||||
|
self.assertEqual(len(captured_queries), 1)
|
||||||
|
for name, value in options.items():
|
||||||
|
option = '{} {}'.format(name.upper(), 'true' if value else 'false')
|
||||||
|
self.assertIn(option, captured_queries[0]['sql'])
|
||||||
|
|
||||||
|
@unittest.skipUnless(connection.vendor == 'mysql', 'MySQL specific')
|
||||||
|
def test_mysql_text_to_traditional(self):
|
||||||
|
with CaptureQueriesContext(connection) as captured_queries:
|
||||||
|
Tag.objects.filter(name='test').explain(format='text')
|
||||||
|
self.assertEqual(len(captured_queries), 1)
|
||||||
|
self.assertIn('FORMAT=TRADITIONAL', captured_queries[0]['sql'])
|
||||||
|
|
||||||
|
@unittest.skipUnless(connection.vendor == 'mysql', 'MySQL < 5.7 specific')
|
||||||
|
def test_mysql_extended(self):
|
||||||
|
# Inner skip to avoid module level query for MySQL version.
|
||||||
|
if not connection.features.needs_explain_extended:
|
||||||
|
raise unittest.SkipTest('MySQL < 5.7 specific')
|
||||||
|
qs = Tag.objects.filter(name='test')
|
||||||
|
with CaptureQueriesContext(connection) as captured_queries:
|
||||||
|
qs.explain(format='json')
|
||||||
|
self.assertEqual(len(captured_queries), 1)
|
||||||
|
self.assertNotIn('EXTENDED', captured_queries[0]['sql'])
|
||||||
|
with CaptureQueriesContext(connection) as captured_queries:
|
||||||
|
qs.explain(format='text')
|
||||||
|
self.assertEqual(len(captured_queries), 1)
|
||||||
|
self.assertNotIn('EXTENDED', captured_queries[0]['sql'])
|
||||||
|
|
||||||
|
|
||||||
|
@skipIfDBFeature('supports_explaining_query_execution')
|
||||||
|
class ExplainUnsupportedTests(TestCase):
|
||||||
|
|
||||||
|
def test_message(self):
|
||||||
|
msg = 'This backend does not support explaining query execution.'
|
||||||
|
with self.assertRaisesMessage(NotSupportedError, msg):
|
||||||
|
Tag.objects.filter(name='test').explain()
|
|
@ -20,6 +20,14 @@ from django.test.utils import get_runner
|
||||||
from django.utils.deprecation import RemovedInDjango30Warning
|
from django.utils.deprecation import RemovedInDjango30Warning
|
||||||
from django.utils.log import DEFAULT_LOGGING
|
from django.utils.log import DEFAULT_LOGGING
|
||||||
|
|
||||||
|
try:
|
||||||
|
import MySQLdb
|
||||||
|
except ImportError:
|
||||||
|
pass
|
||||||
|
else:
|
||||||
|
# Ignore informational warnings from QuerySet.explain().
|
||||||
|
warnings.filterwarnings('ignore', '\(1003, *', category=MySQLdb.Warning)
|
||||||
|
|
||||||
# Make deprecation warnings errors to ensure no usage of deprecated features.
|
# Make deprecation warnings errors to ensure no usage of deprecated features.
|
||||||
warnings.simplefilter("error", RemovedInDjango30Warning)
|
warnings.simplefilter("error", RemovedInDjango30Warning)
|
||||||
# Make runtime warning errors to ensure no usage of error prone patterns.
|
# Make runtime warning errors to ensure no usage of error prone patterns.
|
||||||
|
|
Loading…
Reference in New Issue