Fix sqlite3.Connection.iterdump on tables/fields with reserved names or quotes

Closes #9750
This commit is contained in:
Petri Lehtinen 2012-02-12 21:05:31 +02:00
parent 54411c1784
commit 51d04d1ba8
4 changed files with 41 additions and 22 deletions

View File

@ -1,6 +1,12 @@
# Mimic the sqlite3 console shell's .dump command # Mimic the sqlite3 console shell's .dump command
# Author: Paul Kippes <kippesp@gmail.com> # Author: Paul Kippes <kippesp@gmail.com>
# Every identifier in sql is quoted based on a comment in sqlite
# documentation "SQLite adds new keywords from time to time when it
# takes on new features. So to prevent your code from being broken by
# future enhancements, you should normally quote any identifier that
# is an English language word, even if you do not have to."
def _iterdump(connection): def _iterdump(connection):
""" """
Returns an iterator to the dump of the database in an SQL text format. Returns an iterator to the dump of the database in an SQL text format.
@ -15,49 +21,49 @@ def _iterdump(connection):
# sqlite_master table contains the SQL CREATE statements for the database. # sqlite_master table contains the SQL CREATE statements for the database.
q = """ q = """
SELECT name, type, sql SELECT "name", "type", "sql"
FROM sqlite_master FROM "sqlite_master"
WHERE sql NOT NULL AND WHERE "sql" NOT NULL AND
type == 'table' "type" == 'table'
""" """
schema_res = cu.execute(q) schema_res = cu.execute(q)
for table_name, type, sql in schema_res.fetchall(): for table_name, type, sql in sorted(schema_res.fetchall()):
if table_name == 'sqlite_sequence': if table_name == 'sqlite_sequence':
yield('DELETE FROM sqlite_sequence;') yield('DELETE FROM "sqlite_sequence";')
elif table_name == 'sqlite_stat1': elif table_name == 'sqlite_stat1':
yield('ANALYZE sqlite_master;') yield('ANALYZE "sqlite_master";')
elif table_name.startswith('sqlite_'): elif table_name.startswith('sqlite_'):
continue continue
# NOTE: Virtual table support not implemented # NOTE: Virtual table support not implemented
#elif sql.startswith('CREATE VIRTUAL TABLE'): #elif sql.startswith('CREATE VIRTUAL TABLE'):
# qtable = table_name.replace("'", "''") # qtable = table_name.replace("'", "''")
# yield("INSERT INTO sqlite_master(type,name,tbl_name,rootpage,sql)"\ # yield("INSERT INTO sqlite_master(type,name,tbl_name,rootpage,sql)"\
# "VALUES('table','%s','%s',0,'%s');" % # "VALUES('table','{0}','{0}',0,'{1}');".format(
# qtable, # qtable,
# qtable, # sql.replace("''")))
# sql.replace("''"))
else: else:
yield('%s;' % sql) yield('{0};'.format(sql))
# Build the insert statement for each row of the current table # Build the insert statement for each row of the current table
res = cu.execute("PRAGMA table_info('%s')" % table_name) table_name_ident = table_name.replace('"', '""')
res = cu.execute('PRAGMA table_info("{0}")'.format(table_name_ident))
column_names = [str(table_info[1]) for table_info in res.fetchall()] column_names = [str(table_info[1]) for table_info in res.fetchall()]
q = "SELECT 'INSERT INTO \"%(tbl_name)s\" VALUES(" q = """SELECT 'INSERT INTO "{0}" VALUES({1})' FROM "{0}";""".format(
q += ",".join(["'||quote(" + col + ")||'" for col in column_names]) table_name_ident,
q += ")' FROM '%(tbl_name)s'" ",".join("""'||quote("{0}")||'""".format(col.replace('"', '""')) for col in column_names))
query_res = cu.execute(q % {'tbl_name': table_name}) query_res = cu.execute(q)
for row in query_res: for row in query_res:
yield("%s;" % row[0]) yield("{0};".format(row[0]))
# Now when the type is 'index', 'trigger', or 'view' # Now when the type is 'index', 'trigger', or 'view'
q = """ q = """
SELECT name, type, sql SELECT "name", "type", "sql"
FROM sqlite_master FROM "sqlite_master"
WHERE sql NOT NULL AND WHERE "sql" NOT NULL AND
type IN ('index', 'trigger', 'view') "type" IN ('index', 'trigger', 'view')
""" """
schema_res = cu.execute(q) schema_res = cu.execute(q)
for name, type, sql in schema_res.fetchall(): for name, type, sql in schema_res.fetchall():
yield('%s;' % sql) yield('{0};'.format(sql))
yield('COMMIT;') yield('COMMIT;')

View File

@ -13,6 +13,14 @@ class DumpTests(unittest.TestCase):
def CheckTableDump(self): def CheckTableDump(self):
expected_sqls = [ expected_sqls = [
"""CREATE TABLE "index"("index" blob);"""
,
"""INSERT INTO "index" VALUES(X'01');"""
,
"""CREATE TABLE "quoted""table"("quoted""field" text);"""
,
"""INSERT INTO "quoted""table" VALUES('quoted''value');"""
,
"CREATE TABLE t1(id integer primary key, s1 text, " \ "CREATE TABLE t1(id integer primary key, s1 text, " \
"t1_i1 integer not null, i2 integer, unique (s1), " \ "t1_i1 integer not null, i2 integer, unique (s1), " \
"constraint t1_idx1 unique (i2));" "constraint t1_idx1 unique (i2));"

View File

@ -503,6 +503,7 @@ Lenny Kneler
Pat Knight Pat Knight
Greg Kochanski Greg Kochanski
Damon Kohler Damon Kohler
Marko Kohtala
Vlad Korolev Vlad Korolev
Joseph Koshy Joseph Koshy
Maksim Kozyarchuk Maksim Kozyarchuk

View File

@ -113,6 +113,10 @@ Core and Builtins
Library Library
------- -------
- Issue #9750: Fix sqlite3.Connection.iterdump on tables and fields
with a name that is a keyword or contains quotes. Patch by Marko
Kohtala.
- Issue #10287: nntplib now queries the server's CAPABILITIES again after - Issue #10287: nntplib now queries the server's CAPABILITIES again after
authenticating (since the result may change, according to RFC 4643). authenticating (since the result may change, according to RFC 4643).
Patch by Hynek Schlawack. Patch by Hynek Schlawack.