Skip to content

fix: escape column names and handle mismatched data types in D1 SQL dump #9866

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 4 commits into from
Jul 18, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
8 changes: 8 additions & 0 deletions .changeset/mean-schools-see.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
---
"miniflare": patch
---

Fix D1 SQL dump generation: escape identifiers and handle SQLite's dynamic typing

Escape column and table names to prevent SQL syntax errors.
Escape values based on their runtime type to support SQLite's flexible typing.
42 changes: 30 additions & 12 deletions packages/miniflare/src/workers/d1/dumpSql.ts
Original file line number Diff line number Diff line change
Expand Up @@ -19,13 +19,14 @@ export function* dumpSql(
// Taken from SQLite shell.c.in https://github.com/sqlite/sqlite/blob/105c20648e1b05839fd0638686b95f2e3998abcb/src/shell.c.in#L8463-L8469
// @ts-ignore (SqlStorageStatement needs to be callable)
const tables_cursor = db.prepare(`
SELECT name, type, sql
FROM sqlite_schema AS o
WHERE (true) AND type=='table'
AND sql NOT NULL
SELECT name, type, sql
FROM sqlite_schema AS o
WHERE (true) AND type=='table'
AND sql NOT NULL
ORDER BY tbl_name='sqlite_sequence', rowid;
`)();
const tables: any[] = Array.from(tables_cursor);
const tables: { name: string; type: string; sql: string }[] =
Array.from(tables_cursor);

for (const { name: table, sql } of tables) {
if (filterTables.size > 0 && !filterTables.has(table)) continue;
Expand Down Expand Up @@ -54,20 +55,28 @@ export function* dumpSql(
}

if (noData) continue;
const columns_cursor = db.exec(`PRAGMA table_info="${table}"`);
const columns = Array.from(columns_cursor);
const select = `SELECT ${columns.map((c) => c.name).join(", ")}
FROM "${table}";`;
const columns_cursor = db.exec(`PRAGMA table_info=${escapeId(table)}`);

const columns = Array.from(columns_cursor) as {
cid: string;
name: string;
type: string;
notnull: number;
dflt_val: string | null;
pk: number;
}[];

const select = `SELECT ${columns.map((c) => escapeId(c.name)).join(", ")} FROM ${escapeId(table)};`;
const rows_cursor = db.exec(select);
for (const dataRow of rows_cursor.raw()) {
const formattedCells = dataRow.map((cell: unknown, i: number) => {
const colType = columns[i].type;
const cellType = typeof cell;
if (cell === null) {
return "NULL";
} else if (colType === "INTEGER" || cellType === "number") {
} else if (cellType === "number") {
return cell;
} else if (colType === "TEXT" || cellType === "string") {
} else if (cellType === "string") {
return outputQuotedEscapedString(cell);
} else if (cell instanceof ArrayBuffer) {
return `X'${Array.prototype.map
Expand All @@ -79,7 +88,7 @@ export function* dumpSql(
}
});

yield `INSERT INTO ${sqliteQuote(table)} VALUES(${formattedCells.join(",")});`;
yield `INSERT INTO ${escapeId(table)} VALUES(${formattedCells.join(",")});`;
}
}

Expand Down Expand Up @@ -138,6 +147,15 @@ export function sqliteQuote(token: string) {
: token;
}

/**
* Escape an identifier for use in SQL statements.
* @param id - The identifier to escape.
* @returns
*/
function escapeId(id: string) {
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

SQLite escapes double quotes in identifiers by doubling them using sqlite3_mprintf("\"%w\"", azCol[i])
https://github.com/sqlite/sqlite/blob/master/src/shell.c.in#L2914

The %w format doubles " as "":
https://github.com/sqlite/sqlite/blob/master/src/printf.c#L34

return `"${id.replace(/"/g, '""')}"`;
}

// List taken from `aKeywordTable` inhttps://github.com/sqlite/sqlite/blob/378bf82e2bc09734b8c5869f9b148efe37d29527/tool/mkkeywordhash.c#L172
// prettier-ignore
export const SQLITE_KEYWORDS = new Set([
Expand Down
149 changes: 149 additions & 0 deletions packages/miniflare/test/plugins/d1/suite.ts
Original file line number Diff line number Diff line change
@@ -1,8 +1,11 @@
import assert from "assert";
import fs from "fs/promises";
import { type D1Database } from "@cloudflare/workers-types/experimental";
import { ExecutionContext } from "ava";
import { Miniflare, MiniflareOptions } from "miniflare";
import { useTmp, utf8Encode } from "../../test-shared";
import { binding, getDatabase, opts, test } from "./test";
import type { Context } from "./test";

export const SCHEMA = (
tableColours: string,
Expand Down Expand Up @@ -580,3 +583,149 @@ test("it properly handles ROWS_AND_COLUMNS results format", async (t) => {
}
t.deepEqual(results, expectedResults);
});

/**
* Test that the `dumpSql` method returns a valid SQL dump of the database.
* This test creates a new D1 database, fills it with dummy data, and then
* exports the SQL dump using the `PRAGMA miniflare_d1_export` command.
* It then executes the dump in a new D1 database and checks if both databases
* are equal in terms of schema and data.
*/
test("dumpSql exports and imports complete database structure and content correctly", async (t) => {
// Create a new Miniflare instance with D1 database
const originalMF = new Miniflare({
...opts,
d1Databases: { test: "test" },
});
const mirrorMF = new Miniflare({
...opts,
d1Databases: { test: "test" },
});

t.teardown(() => originalMF.dispose());
t.teardown(() => mirrorMF.dispose());

const originalDb = await originalMF.getD1Database("test");
const mirrorDb = await mirrorMF.getD1Database("test");

// Fill the original database with dummy data
await fillDummyData(originalDb);

// Export the database schema and data
const result = await originalDb
.prepare("PRAGMA miniflare_d1_export(?,?,?);")
.bind(0, 0)
.raw();

const [dumpStatements] = result as [string[]];
const dump = dumpStatements.join("\n");

await mirrorDb.exec(dump);

// Verify that the schema and data in both databases are equal
await isDatabaseEqual(t, originalDb, mirrorDb);
});

/**
* Populates a D1 database with test data for schema export testing.
* Creates tables with various schema features (foreign keys, special characters, etc.)
* and inserts sample data including edge cases like NULL values and type mismatches.
*/
async function fillDummyData(db: D1Database) {
// Create schema with various SQL features to test export compatibility
// Each table must have an ID column as primary key so that we can use it for ordering in equality tests

const schemas = [
// Create basic table with text primary key
`CREATE TABLE "classrooms"(id TEXT PRIMARY KEY, capacity INTEGER, test_blob BLOB)`,

// Create table with foreign key constraint
`CREATE TABLE "students" (id INTEGER PRIMARY KEY, name TEXT NOT NULL, classroom TEXT NOT NULL, FOREIGN KEY (classroom) REFERENCES "classrooms" (id) ON DELETE CASCADE)`,

// Create table with spaces in name to test quoting
`CREATE TABLE "test space table" (id INTEGER PRIMARY KEY, name TEXT NOT NULL)`,

// Create table with escaped quotes and SQL reserved keywords
`CREATE TABLE "test""name" (id INTEGER PRIMARY KEY, "escaped""column" TEXT, "order" INTEGER)`,
];

await db.exec(schemas.join(";"));

// Prepare sample data
const classroomData = [
// Standard numeric data
...Array.from({ length: 10 }, (_, i) => ({
id: `classroom_${i + 1}`,
capacity: (i + 1) * 10,
test_blob: utf8Encode(`Blob data for classroom ${i + 1}`),
})),

// Edge case: type mismatch (string where number expected)
{ id: "different_type_classroom", capacity: "not_a_number" },

// Edge case: NULL value
{ id: "null_classroom", capacity: null },
];

// Insert classroom data
const classroomStmt = db.prepare(
`INSERT INTO classrooms (id, capacity) VALUES (?, ?)`
);

for (const classroom of classroomData) {
await classroomStmt.bind(classroom.id, classroom.capacity).run();
}

// Generate and insert student data with classroom references
const studentStmt = db.prepare(
`INSERT INTO students (id, name, classroom) VALUES (?, ?, ?)`
);

// Create 2 students for each classroom
for (let i = 0; i < 10; i++) {
for (let j = 1; j <= 2; j++) {
const studentId = i * 2 + j;
await studentStmt
.bind(studentId, `student_${studentId}`, `classroom_${i + 1}`)
.run();
}
}
}

/**
* Compares two D1 databases to check if they are equal in terms of schema and data.
* It retrieves the schema of both databases, compares the tables, and then
* checks if the data in each table is identical.
*/
async function isDatabaseEqual(
t: ExecutionContext<Context>,
db: D1Database,
db2: D1Database
) {
// SQL to select schema excluding internal tables
const selectSchemaSQL =
"SELECT * FROM sqlite_master WHERE type = 'table' AND (name NOT LIKE 'sqlite_%' AND name NOT LIKE '_cf_%')";

// Check if schema (tables) in both databases is equal
const tablesFromMirror = (await db2.prepare(selectSchemaSQL).all()).results;
const tablesFromOriginal = (await db.prepare(selectSchemaSQL).all()).results;
t.deepEqual(tablesFromMirror, tablesFromOriginal);

// Check if data in each table is equal
// We will use a simple SELECT * FROM table ORDER BY id to ensure consistent ordering
for (const table of tablesFromMirror) {
const tableName = table.name as string;

// Escape and ORDER BY to ensure consistent ordering
const selectTableSQL = `SELECT * FROM "${tableName.replace(/"/g, '""')}" ORDER BY id ASC`;

const originalData = (await db.prepare(selectTableSQL).all()).results;
const mirrorData = (await db2.prepare(selectTableSQL).all()).results;

t.deepEqual(
originalData,
mirrorData,
`Data mismatch in table: ${tableName}`
);
}
}
12 changes: 6 additions & 6 deletions packages/wrangler/src/__tests__/d1/export.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -59,14 +59,14 @@ describe("export", () => {
const create_foo = "CREATE TABLE foo(id INTEGER PRIMARY KEY, value TEXT);";
const create_bar = "CREATE TABLE bar(id INTEGER PRIMARY KEY, value TEXT);";
const insert_foo = [
"INSERT INTO foo VALUES(1,'xxx');",
"INSERT INTO foo VALUES(2,'yyy');",
"INSERT INTO foo VALUES(3,'zzz');",
`INSERT INTO "foo" VALUES(1,'xxx');`,
`INSERT INTO "foo" VALUES(2,'yyy');`,
`INSERT INTO "foo" VALUES(3,'zzz');`,
];
const insert_bar = [
"INSERT INTO bar VALUES(1,'aaa');",
"INSERT INTO bar VALUES(2,'bbb');",
"INSERT INTO bar VALUES(3,'ccc');",
`INSERT INTO "bar" VALUES(1,'aaa');`,
`INSERT INTO "bar" VALUES(2,'bbb');`,
`INSERT INTO "bar" VALUES(3,'ccc');`,
];

// Full export
Expand Down
Loading