Opened 16 years ago
Closed 2 years ago
#10070 closed Bug (fixed)
Named parameters not working on raw sql queries with sqlite
Reported by: | Matias Surdi | Owned by: | Ryan Cheley |
---|---|---|---|
Component: | Database layer (models, ORM) | Version: | dev |
Severity: | Normal | Keywords: | |
Cc: | shai@…, mike@…, Joseph Gordon | 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 (last modified by )
The following code shows the problem when using sqlite:
$ python manage.py shell Python 2.5.2 (r252:60911, Oct 5 2008, 19:29:17) [GCC 4.3.2] on linux2 Type "help", "copyright", "credits" or "license" for more information. (InteractiveConsole) >>> from django.db import connection >>> c = connection.cursor() >>> c.execute("select name from inventory_host where id=%(id)s",{'id':'1'}) Traceback (most recent call last): File "<console>", line 1, in <module> File "/usr/lib/python2.5/site-packages/django/db/backends/util.py", line 19, in execute return self.cursor.execute(sql, params) File "/usr/lib/python2.5/site-packages/django/db/backends/sqlite3/base.py", line 167, in execute query = self.convert_query(query, len(params)) File "/usr/lib/python2.5/site-packages/django/db/backends/sqlite3/base.py", line 179, in convert_query return query % tuple("?" * num_params) TypeError: format requires a mapping >>> >>> import django >>> django.VERSION (1, 0, 2, 'final', 0)
$ sqlite3 --version 3.5.9
When using Mysql or Postgres, that works (not tested by me, but by others on django-users).
Attachments (2)
Change History (36)
comment:1 by , 16 years ago
Description: | modified (diff) |
---|
follow-up: 10 comment:2 by , 16 years ago
Adding info from the django-users thread:
SQLite and Oracle backends don't support this. In fact, Oracle used to have this and it was deleted in [9418] in response to a ticket (#9478) that reported it was faulty with this commit message "Removed support for passing params as dicts in the oracle backend. Wasn't documented, didn't work, isn't necessary".
The relevant docs (http://docs.djangoproject.com/en/dev/topics/db/sql/#topics-db-sql) don't state clearly if using named parameter marker plus a mapping is supported or not, so maybe this is a documentation issue?.
comment:3 by , 16 years ago
The main reason for removing it from Oracle was that it never worked in the first place, nobody seemed to be using it, and it didn't seem worthwhile to maintain at the time. If there is demand to add this as an explicitly documented feature, I'd be happy to put it back in.
comment:4 by , 16 years ago
I'm attaching a patch for SQLite.
With this patch, now the parameters can be passed as a dict, and the query can contain %(parameter)s as with mysql or postgres.
comment:5 by , 16 years ago
Triage Stage: | Unreviewed → Design decision needed |
---|
comment:6 by , 16 years ago
Component: | Uncategorized → Database layer (models, ORM) |
---|---|
Needs tests: | set |
comment:7 by , 15 years ago
I've attached a different fix (http://code.djangoproject.com/attachment/ticket/10070/base.diff) for this (though similar in places to msurdi's). Sorry about the annonymous user on the attachement, but I didn't see how to combine it with this.
It should be faster in the apparently more common case of supplying a sequence, since the only extra overhead is the try block setup.
Also, since the text replacement is done by the format operator itself, I'm more confident that the result will be correct, where I have to worry about missing the fact that a percent sign is quoted when using the regular expression replace approach of the original patch.
A hint if anyone doesn't find the colonifier to be obvious: the format operator only cares that its right operand has a getitem method. (Tested with python versions 2.4 and 2.6.)
This now allows my PostgreSQL developed mapping queries to work with sqlite3 (Django-1.0.3, python 2.6).
Sadly, I have no test.py code to offer.
Bill
comment:8 by , 14 years ago
Severity: | → Normal |
---|---|
Type: | → Bug |
comment:9 by , 13 years ago
Easy pickings: | unset |
---|---|
Triage Stage: | Design decision needed → Accepted |
UI/UX: | unset |
Based on Ramiro's and Ian's input in the first comments, there's no fundamental reason not to support named parameters on Oracle and SQL, it's just a matter of writing a solid implementation.
comment:10 by , 12 years ago
Cc: | added |
---|---|
Has patch: | set |
Replying to ramiro:
In fact, Oracle used to have this and it was deleted in [9418] in response to a ticket (#9478)
For future reference, the relevant ticket is #9408. The code that was removed indeed did not really support named parameters (except by names "arg0", "arg1" etc.).
Pull Request 411 supports named parameters for real. No tests provided (it still isn't a documented feature as far as I know...). I can do the documentation and add tests if this is deemed required.
comment:12 by , 12 years ago
Cc: | added |
---|
comment:13 by , 11 years ago
I started a related discussion here https://groups.google.com/forum/#!topic/django-developers/ts14HX9Yz0I
named parameters do currently work with some db interfaces but the code breaks on the repr() method of a RawQuerySet:
param = dict(lname = 'Doe')
qs = Person.objects.raw('SELECT * FROM myapp_person WHERE last_name = %(lname)s', param)
repr(qs)
/home/user/vpy/dev/lib/python2.7/site-packages/django/db/models/query.pyc
in repr(self)
1530
1531 def repr(self):
-> 1532 return "<RawQuerySet: %r>" % (self.raw_query %
tuple(self.params))
1533
1534 def getitem(self, k):
TypeError: format requires a mapping
comment:15 by , 9 years ago
Cc: | added |
---|
follow-up: 17 comment:16 by , 6 years ago
Version: | 1.0 → master |
---|
This still breaks on SQLite (3.27.2), although with a less helpful error message:
Traceback (most recent call last): File "<console>", line 1, in <module> File "/home/rixx/.local/share/virtualenvs/demo/lib/python3.7/site-packages/django/db/backends/utils.py", line 67, in execute return self._execute_with_wrappers(sql, params, many=False, executor=self._execute) File "/home/rixx/.local/share/virtualenvs/demo/lib/python3.7/site-packages/django/db/backends/utils.py", line 76, in _execute_with_wrappers return executor(sql, params, many, context) File "/home/rixx/.local/share/virtualenvs/demo/lib/python3.7/site-packages/django/db/backends/utils.py", line 84, in _execute return self.cursor.execute(sql, params) File "/home/rixx/.local/share/virtualenvs/demo/lib/python3.7/site-packages/django/db/utils.py", line 89, in __exit__ raise dj_exc_value.with_traceback(traceback) from exc_value File "/home/rixx/.local/share/virtualenvs/demo/lib/python3.7/site-packages/django/db/backends/utils.py", line 84, in _execute return self.cursor.execute(sql, params) File "/home/rixx/.local/share/virtualenvs/demo/lib/python3.7/site-packages/django/db/backends/sqlite3/base.py", line 383, in execute return Database.Cursor.execute(self, query, params) django.db.utils.OperationalError: near "%": syntax error
This syntax isn't documented (as far as I can see, at least not in topics/db/sql
) – do we want to add documentation for this, and exclude SQLite?
comment:17 by , 6 years ago
Replying to Tobias Kunze:
This syntax isn't documented (as far as I can see, at least not in
topics/db/sql
) – do we want to add documentation for this, and exclude SQLite?
That much I did almost six years ago, as noted in comment:14 -- and it is still there.
comment:18 by , 5 years ago
I don't know how recent it is, but sqlite does support named parameters, albeit with a different syntax [1].
Both of these work on my machine:
c.execute("select name from inventory_host where id=:id", {'id': '1'}) Host.objects.raw("select * from inventory_host where id=:id", {'id': '1'})
Do we want to try and make the syntax consistent across all backends or would it be enough to document the syntax for each one?
[1] https://docs.python.org/3/library/sqlite3.html#sqlite3.Cursor.execute
comment:19 by , 5 years ago
Do we want to try and make the syntax consistent across all backends or would it be enough to document the syntax for each one?
Given the most common use case of raw
and execute
is to perform non database-agnostic SQL I think documenting the syntax would be fine and easier to maintain. I think we already so format massaging for Oracle though.
comment:20 by , 4 years ago
I encountered a use case where I wanted to do an upsert query (INSERT ... ON CONFLICT DO UPDATE SET ...
). This is raw SQL that is not supported by the ORM, but has consistent syntax between sqlite and postgresql. I ran into this trouble with named parameters. The query syntax itself worked for both backends, but the parameter naming syntax did not. I worked around this by just using positional arguments instead -- but there are valid needs for raw SQL targeting more than one database backend, and consistent named parameter syntax would be useful.
comment:21 by , 2 years ago
Owner: | changed from | to
---|---|
Status: | new → assigned |
I'm at DjangoCon US and I'm looking into this ticket
comment:22 by , 2 years ago
Resolution: | → fixed |
---|---|
Status: | assigned → closed |
In looking at the tests in raw_query\tests
I see a few tests that already exist:
test_params
(name refactored in [Fix camelCase test names](https://code.djangoproject.com/ticket/22909), added in [Add a method to the orm to create Model instances from raw sql queries](https://code.djangoproject.com/ticket/11863))test_params_none
(added [It should be possible to pass None as params for Model.objects.raw](https://code.djangoproject.com/ticket/32231))test_pyformat_params
(name refactored in [Fix camelCase test names](https://code.djangoproject.com/ticket/22909), added in [PR 411](https://github.com/django/django/pull/411))
These are already available and appear to be testing the very thing that the ticket is asking for.
Charlie DeTar, is there anything that is being missed here?
comment:24 by , 2 years ago
Resolution: | fixed |
---|---|
Status: | closed → new |
Sorry -- this is still broken on Sqlite. The additions and fixes mentioned in comment:22 are mostly for Oracle and other backends. The Sqlite backend, at the time I write this, still has
supports_paramstyle_pyformat = False
and still borks with a syntax error if you try to replicate the session in the ticket description.
follow-up: 26 comment:25 by , 2 years ago
Shai Berger can you confirm which version of SQLite you are using?
comment:26 by , 2 years ago
Replying to Ryan Cheley:
Shai Berger can you confirm which version of SQLite you are using?
Python 3.10.7 (main, Oct 1 2022, 04:31:04) [GCC 12.2.0] on linux Type "help", "copyright", "credits" or "license" for more information. >>> import sqlite3 >>> sqlite3.sqlite_version '3.39.4'
(in the env where I checked)
follow-up: 28 comment:27 by , 2 years ago
I've done a bit of research and it looks like django.db.backends.sqlite3.base
has a class called SQLiteCursorWrapper
.
This in turn has a method convert_query
which per the doc string of the SQLiteCursorWrapper
method does:
Django uses "format" style placeholders, but pysqlite2 uses "qmark" style.
This fixes it -- but note that if you want to use a literal "%s" in a query,
you'll need to use "%%s".
I think the way to fix the issue is to update that method to include the following logic:
query = re.sub("\)s", "", re.sub("%\(", ":", query))
this will convert the string passed using the expectations of the ORM API to what SQLite is expecting for parameters, i.e. a passed in query will go from this
'select * from content_injuredlist where id = %(id)s and app_name = %(app_name)s'
to this
'select * from content_injuredlist where id = :id and app_name = :app_name'
which will then work with SQLite
Still to do:
- Update the method
- Write any tests
- submit PR
comment:28 by , 2 years ago
Replying to Ryan Cheley:
I think the way to fix the issue is to update that method to include the following logic:
query = re.sub("\)s", "", re.sub("%\(", ":", query))
This looks quite fragile (consider, e.g. a query which, for whatever reason, includes )s
in a string constant).
A more robust approach is to create a naming-dict from all the param-names, and use that to format the original text:
naming_dict = { param: f":{param}" for param in param_names} query = query % naming_dict
Where param_names
can be collected either by parsing the query, or from the parameters given.
(take a look at the Oracle backend -- I wrote that piece too long ago to remember which it takes, but at the time I knew what I was doing there)
comment:29 by , 2 years ago
I agree with Shai that we should avoid using regex here.
The most straightforward solution I can think of, I haven't looked at the Oracle implementation in details, would be to simply implement __getitem__
class SQLiteParams: def __getitem__(self, param): return f":{param}" sql = sql % SQLiteParams()
This will ensure the backend reports the low level missing param message in cases a parameter is missing instead of a KeyError
during the Django translation phase
comment:30 by , 2 years ago
Thanks for the feed back Shai and Simon. I will take a look and see how I can work that into the solution.
comment:31 by , 2 years ago
Patch needs improvement: | set |
---|---|
Status: | new → assigned |
comment:32 by , 2 years ago
I've implemented the solution as outlined by Shia.
I'll be making changes to the documentation as suggested by Simon here https://github.com/django/django/pull/16243#pullrequestreview-1161175532 next
comment:33 by , 2 years ago
Needs tests: | unset |
---|---|
Patch needs improvement: | unset |
Triage Stage: | Accepted → Ready for checkin |
(description formatting)