Skip to content

Commit f0890c4

Browse files
committed
Merge pull request #55907 from ruyrocha/fix/sqlite3-data-loss
[#55866] Fix SQLite3 data loss during table alterations with CASCADE foreign keys.
1 parent 4663af7 commit f0890c4

File tree

3 files changed

+153
-2
lines changed

3 files changed

+153
-2
lines changed

activerecord/CHANGELOG.md

Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,3 +1,28 @@
1+
* Fix SQLite3 data loss during table alterations with CASCADE foreign keys.
2+
3+
When altering a table in SQLite3 that is referenced by child tables with
4+
`ON DELETE CASCADE` foreign keys, ActiveRecord would silently delete all
5+
data from the child tables. This occurred because SQLite requires table
6+
recreation for schema changes, and during this process the original table
7+
is temporarily dropped, triggering CASCADE deletes on child tables.
8+
9+
The root cause was incorrect ordering of operations. The original code
10+
wrapped `disable_referential_integrity` inside a transaction, but
11+
`PRAGMA foreign_keys` cannot be modified inside a transaction in SQLite -
12+
attempting to do so simply has no effect. This meant foreign keys remained
13+
enabled during table recreation, causing CASCADE deletes to fire.
14+
15+
The fix reverses the order to follow the official SQLite 12-step ALTER TABLE
16+
procedure: `disable_referential_integrity` now wraps the transaction instead
17+
of being wrapped by it. This ensures foreign keys are properly disabled
18+
before the transaction starts and re-enabled after it commits, preventing
19+
CASCADE deletes while maintaining data integrity through atomic transactions.
20+
21+
*Ruy Rocha*
22+
23+
* Fix negative scopes for enums to include records with `nil` values.
24+
25+
126
## Rails 8.1.0.rc1 (October 15, 2025) ##
227

328
* Add replicas to test database parallelization setup.

activerecord/lib/active_record/connection_adapters/sqlite3_adapter.rb

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -613,8 +613,8 @@ def alter_table(
613613
yield definition if block_given?
614614
end
615615

616-
transaction do
617-
disable_referential_integrity do
616+
disable_referential_integrity do
617+
transaction do
618618
move_table(table_name, altered_table_name, options.merge(temporary: true))
619619
move_table(altered_table_name, table_name, &caller)
620620
end

activerecord/test/cases/adapters/sqlite3/sqlite3_adapter_test.rb

Lines changed: 126 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1095,6 +1095,132 @@ def test_integer_cpk_column_returns_false_for_rowid
10951095
end
10961096
end
10971097

1098+
def test_alter_table_with_fk_preserves_rows_when_referenced_table_altered
1099+
conn = SQLite3Adapter.new(database: ":memory:", adapter: "sqlite3", strict: false)
1100+
1101+
conn.create_table :authors do |t|
1102+
t.string :name, null: false
1103+
end
1104+
1105+
conn.create_table :books do |t|
1106+
t.string :title, null: false
1107+
t.integer :author_id, null: false
1108+
end
1109+
conn.add_foreign_key :books, :authors, on_delete: :cascade
1110+
1111+
conn.execute("INSERT INTO authors (id, name) VALUES (1, 'Douglas Adams');")
1112+
conn.execute("INSERT INTO books (id, title, author_id) VALUES (42, 'The Hitchhiker''s Guide', 1);")
1113+
conn.execute("INSERT INTO books (id, title, author_id) VALUES (43, 'Restaurant at the End', 1);")
1114+
1115+
initial_book_count = conn.select_value("SELECT COUNT(*) FROM books")
1116+
assert_equal 2, initial_book_count
1117+
1118+
conn.add_column :authors, :email, :string
1119+
1120+
book_count = conn.select_value("SELECT COUNT(*) FROM books")
1121+
author_count = conn.select_value("SELECT COUNT(*) FROM authors")
1122+
1123+
assert_equal 2, book_count, "Books were CASCADE deleted when authors table was altered!"
1124+
assert_equal 1, author_count, "Authors were lost during table alteration!"
1125+
ensure
1126+
conn.disconnect! if conn
1127+
end
1128+
1129+
def test_alter_table_with_fk_preserves_rows_when_adding_fk_to_referenced_table
1130+
conn = SQLite3Adapter.new(database: ":memory:", adapter: "sqlite3", strict: false)
1131+
1132+
conn.create_table :groups do |t|
1133+
t.string :name, null: false
1134+
end
1135+
1136+
conn.create_table :users do |t|
1137+
t.string :username, null: false
1138+
end
1139+
1140+
conn.create_table :reports do |t|
1141+
t.string :title, null: false
1142+
t.integer :group_id, null: false
1143+
end
1144+
conn.add_foreign_key :reports, :groups, on_delete: :cascade
1145+
1146+
conn.execute("INSERT INTO groups (id, name) VALUES (1, 'Admin Group');")
1147+
conn.execute("INSERT INTO users (id, username) VALUES (1, 'alice');")
1148+
conn.execute("INSERT INTO reports (id, title, group_id) VALUES (1, 'Report A', 1);")
1149+
conn.execute("INSERT INTO reports (id, title, group_id) VALUES (2, 'Report B', 1);")
1150+
1151+
initial_report_count = conn.select_value("SELECT COUNT(*) FROM reports")
1152+
assert_equal 2, initial_report_count
1153+
1154+
conn.add_column :groups, :owner_id, :integer
1155+
conn.add_foreign_key :groups, :users, column: :owner_id
1156+
1157+
report_count = conn.select_value("SELECT COUNT(*) FROM reports")
1158+
group_count = conn.select_value("SELECT COUNT(*) FROM groups")
1159+
1160+
assert_equal 2, report_count, "Reports were CASCADE deleted when groups table was altered!"
1161+
assert_equal 1, group_count, "Groups were lost during table alteration!"
1162+
ensure
1163+
conn.disconnect! if conn
1164+
end
1165+
1166+
def test_alter_table_with_multiple_cascade_fks_preserves_all_data
1167+
conn = SQLite3Adapter.new(database: ":memory:", adapter: "sqlite3", strict: false)
1168+
1169+
conn.create_table :authors do |t|
1170+
t.string :name, null: false
1171+
end
1172+
1173+
conn.create_table :books do |t|
1174+
t.string :title, null: false
1175+
t.integer :author_id, null: false
1176+
end
1177+
conn.add_foreign_key :books, :authors, on_delete: :cascade
1178+
1179+
conn.create_table :articles do |t|
1180+
t.string :headline, null: false
1181+
t.integer :author_id, null: false
1182+
end
1183+
conn.add_foreign_key :articles, :authors, on_delete: :cascade
1184+
1185+
conn.execute("INSERT INTO authors (id, name) VALUES (1, 'Douglas Adams');")
1186+
conn.execute("INSERT INTO books (id, title, author_id) VALUES (1, 'HHGTTG', 1);")
1187+
conn.execute("INSERT INTO articles (id, headline, author_id) VALUES (1, 'Towel Day', 1);")
1188+
1189+
conn.add_column :authors, :bio, :text
1190+
1191+
book_count = conn.select_value("SELECT COUNT(*) FROM books")
1192+
article_count = conn.select_value("SELECT COUNT(*) FROM articles")
1193+
1194+
assert_equal 1, book_count, "Books were CASCADE deleted when authors table was altered!"
1195+
assert_equal 1, article_count, "Articles were CASCADE deleted when authors table was altered!"
1196+
ensure
1197+
conn.disconnect! if conn
1198+
end
1199+
1200+
def test_rename_table_with_cascade_fk_preserves_referencing_data
1201+
conn = SQLite3Adapter.new(database: ":memory:", adapter: "sqlite3", strict: false)
1202+
1203+
conn.create_table :authors do |t|
1204+
t.string :name, null: false
1205+
end
1206+
1207+
conn.create_table :books do |t|
1208+
t.string :title, null: false
1209+
t.integer :author_id, null: false
1210+
end
1211+
conn.add_foreign_key :books, :authors, on_delete: :cascade
1212+
1213+
conn.execute("INSERT INTO authors (id, name) VALUES (1, 'Douglas Adams');")
1214+
conn.execute("INSERT INTO books (id, title, author_id) VALUES (1, 'HHGTTG', 1);")
1215+
1216+
conn.rename_table :authors, :writers
1217+
1218+
book_count = conn.select_value("SELECT COUNT(*) FROM books")
1219+
assert_equal 1, book_count, "Books were CASCADE deleted when authors table was renamed!"
1220+
ensure
1221+
conn.disconnect! if conn
1222+
end
1223+
10981224
def test_sqlite_extensions_are_constantized_for_the_client_constructor
10991225
mock_adapter = Class.new(SQLite3Adapter) do
11001226
class << self

0 commit comments

Comments
 (0)