Skip to content

Add ability to create/validate invalid foreign keys in Postgres #27756

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 1 commit into from
Dec 1, 2017

Conversation

travisofthenorth
Copy link
Contributor

@travisofthenorth travisofthenorth commented Jan 20, 2017

Summary

In Postgres, adding foreign keys can cause significant downtime because the transaction needs to acquire some very heavy locks on the table being altered as well as the table being referenced. To illustrate, if I wanted to add a foreign key on my addresses table referencing my users table:

myapp=# BEGIN;
BEGIN
myapp=# ALTER TABLE addresses ADD CONSTRAINT "fk_rails_48c9e0c5a2" FOREIGN KEY ("user_id") REFERENCES "users" ("id");
ALTER TABLE
myapp=# SELECT locktype, relation::regclass, mode, transactionid AS tid, virtualtransaction AS vtid, pid, granted FROM pg_locks;
   locktype    |          relation          |        mode         |   tid   |  vtid   |  pid  | granted
---------------+----------------------------+---------------------+---------+---------+-------+---------
 relation      | pg_locks                   | AccessShareLock     |         | 2/80438 | 56984 | t
 relation      | users_pkey                 | AccessShareLock     |         | 2/80438 | 56984 | t
 relation      | index_addresses_on_user_id | AccessShareLock     |         | 2/80438 | 56984 | t
 relation      | addresses_pkey             | AccessShareLock     |         | 2/80438 | 56984 | t
 virtualxid    |                            | ExclusiveLock       |         | 2/80438 | 56984 | t
 relation      | addresses                  | AccessShareLock     |         | 2/80438 | 56984 | t
 relation      | addresses                  | AccessExclusiveLock |         | 2/80438 | 56984 | t
 transactionid |                            | ExclusiveLock       | 3919702 | 2/80438 | 56984 | t
 relation      | users                      | AccessShareLock     |         | 2/80438 | 56984 | t
 relation      | users                      | RowShareLock        |         | 2/80438 | 56984 | t
 relation      | users                      | AccessExclusiveLock |         | 2/80438 | 56984 | t
(11 rows)

...my transaction acquires an AccessExclusiveLock on users which is extremely detrimental on a high-traffic table, esp. when Postgres performs a potentially lengthy query to validate the check.

On the other hand, I can take a two-step approach which significantly reduces this burden; by introducing an invalid constraint in one transaction and validating it in another, the locks acquired are much less restrictive:

myapp=# BEGIN;
BEGIN
myapp=# ALTER TABLE addresses ADD CONSTRAINT "fk_rails_48c9e0c5a2" FOREIGN KEY ("user_id") REFERENCES "users" ("id") NOT VALID;
ALTER TABLE
myapp=# COMMIT;
COMMIT
myapp=# BEGIN;
BEGIN
myapp=# ALTER TABLE addresses VALIDATE CONSTRAINT "fk_rails_48c9e0c5a2";
ALTER TABLE
myapp=# SELECT locktype, relation::regclass, mode, transactionid AS tid, virtualtransaction AS vtid, pid, granted FROM pg_locks;
   locktype    |          relation          |           mode           |   tid   |  vtid   |  pid  | granted
---------------+----------------------------+--------------------------+---------+---------+-------+---------
 relation      | users_pkey                 | AccessShareLock          |         | 2/80443 | 56984 | t
 relation      | index_addresses_on_user_id | AccessShareLock          |         | 2/80443 | 56984 | t
 relation      | addresses_pkey             | AccessShareLock          |         | 2/80443 | 56984 | t
 relation      | addresses                  | AccessShareLock          |         | 2/80443 | 56984 | t
 relation      | users                      | AccessShareLock          |         | 2/80443 | 56984 | t
 relation      | users                      | RowShareLock             |         | 2/80443 | 56984 | t
 relation      | pg_locks                   | AccessShareLock          |         | 2/80443 | 56984 | t
 virtualxid    |                            | ExclusiveLock            |         | 2/80443 | 56984 | t
 relation      | addresses                  | ShareUpdateExclusiveLock |         | 2/80443 | 56984 | t
 transactionid |                            | ExclusiveLock            | 3919706 | 2/80443 | 56984 | t
(10 rows)

The first transaction acquires the same AccessExclusiveLock on the users table, but "the potentially-lengthy initial check to verify that all rows in the table satisfy the constraint is skipped" (source: postgres docs). Subsequently, the validation step does not block reads or writes on the users table. 💯

So, this PR introduces two things:

  • The ability to create invalid foreign keys by specifying the option valid: false
  • A validate_foreign_key method (which takes the same variety of params as the other foreign key methods) to validate a foreign key

I've heard rumors about this being on the roadmap for the Postgres team, i.e. skipping the check if the table being altered is empty and marking the constraint valid. In any case, perhaps someday this will be more easily achieved with built-in Postgres, but for now it's an issue.

@travisofthenorth
Copy link
Contributor Author

Please advise on any places to add test coverage. I was having a bit of difficulty identifying where to add tests for certain things.

@travisofthenorth
Copy link
Contributor Author

@maclover7 is there a process I should be following for getting some 👀 on this PR? I believe I have some spec failures due to the bundler update issue, but nothing related to this code.

@maclover7
Copy link
Contributor

@travisofthenorth I added the needs feedback label, so hopefully someone will review shortly 😬

@travisofthenorth travisofthenorth force-pushed the validate-foreign-keys branch 4 times, most recently from 7dfe4ab to c396849 Compare January 26, 2017 15:13
@travisofthenorth
Copy link
Contributor Author

@schneems @kaspth just pinging random members at this point...sorry about that. Just wondering if I can get any feedback on this?

@kaspth
Copy link
Contributor

kaspth commented Feb 11, 2017

Sorry don't have the Postgres experience to vet this.

@kamipo you've been doing wonders with Active Record, are you interested in giving this PR a review? 😊

@kamipo
Copy link
Member

kamipo commented Feb 13, 2017

VALIDATE CONSTRAINT works not only foreign key but also CHECK constraint.
And also Oracle have similar feature as NOVALIDATE (novalidate constraint to existing records).

So I prefer the naming here:

  • supports_invalid_foreign_keys? -> supports_validate_constraints?
    • what supports VALIDATE CONSTRAINT means that allowing NOVALIDATE constraint.
  • validate_foreign_key -> validate_constraint
  • not_valid? -> novalidate?

@travisofthenorth travisofthenorth force-pushed the validate-foreign-keys branch 3 times, most recently from f9e6099 to b458c77 Compare February 13, 2017 17:28
@travisofthenorth
Copy link
Contributor Author

travisofthenorth commented Feb 13, 2017

@kamipo updated. A couple things to mention:

@travisofthenorth
Copy link
Contributor Author

Ping @kamipo. Any other feedback?

private
def visit_AddForeignKey(o)
super.tap { |sql| sql << " NOT VALID" if o.novalidate? }
end
Copy link
Member

Choose a reason for hiding this comment

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

SchemaCreation was extracted to lib/active_record/connection_adapters/postgresql/schema_creation.rb.

diff --git a/activerecord/lib/active_record/connection_adapters/postgresql/schema_creation.rb b/activerecord/lib/active_record/connection_adapters/postgresql/schema_creation.rb
index e1d5089115..afb51a92d3 100644
--- a/activerecord/lib/active_record/connection_adapters/postgresql/schema_creation.rb
+++ b/activerecord/lib/active_record/connection_adapters/postgresql/schema_creation.rb
@@ -3,6 +3,10 @@ module ConnectionAdapters
     module PostgreSQL
       class SchemaCreation < AbstractAdapter::SchemaCreation # :nodoc:
         private
+          def visit_AddForeignKey(o)
+            super.tap { |sql| sql << " NOT VALID" if o.novalidate? }
+          end
+
           def add_column_options!(sql, options)
             if options[:collation]
               sql << " COLLATE \"#{options[:collation]}\""

end

def novalidate?
options[:valid] == false
Copy link
Member

Choose a reason for hiding this comment

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

If an adapter doesn't support novalidate constraint, these valid? and novalidate? returns incorrect result.
How about it?

diff --git a/activerecord/lib/active_record/connection_adapters/abstract/schema_definitions.rb b/activerecord/lib/active_record/connection_adapters/abstract/schema_definitions.rb
index 4332318a8e..5127d6bbe9 100644
--- a/activerecord/lib/active_record/connection_adapters/abstract/schema_definitions.rb
+++ b/activerecord/lib/active_record/connection_adapters/abstract/schema_definitions.rb
@@ -58,12 +58,8 @@ def custom_primary_key?
         options[:primary_key] != default_primary_key
       end
 
-      def valid?
-        options[:valid] == true
-      end
-
-      def novalidate?
-        options[:valid] == false
+      def validate?
+        options.fetch(:validate, true)
       end
 
       def defined_for?(to_table_ord = nil, to_table: nil, **options)

@travisofthenorth travisofthenorth force-pushed the validate-foreign-keys branch 5 times, most recently from d8b6275 to 60976c9 Compare February 26, 2017 19:25
@travisofthenorth
Copy link
Contributor Author

K, thanks for letting me know. Sorry for the noise!

@travisofthenorth travisofthenorth force-pushed the validate-foreign-keys branch 5 times, most recently from 2868910 to 3be4619 Compare July 7, 2017 00:48
@travisofthenorth
Copy link
Contributor Author

Rebased on master and resolved a conflict.

@matthewd
Copy link
Member

matthewd commented Jul 8, 2017

I'm a bit worried about how much stuff we're adding to the abstract layer, for a feature that only Postgres supports. Is any of that avoidable? 😕

@schneems
Copy link
Member

schneems commented Jul 8, 2017

I would like to see Rails promote more best practices in regards to database use. Foreign key and other constraints are a huge part of this. On one hand it is catering to a specific database. On the other hand, should users of that DB get a worse experience just because ALL databases don't support that feature?

I know it's not covered in this PR but validation race conditions are a huge issue. Recently I had a validation cause over 80% of ALL load on my postgres database, and I had no idea. Here's the PR explaining the issue and fixing it codetriage/CodeTriage#573.

It would like to see Rails continue to play better with postgres in the future.

@matthewd RE: size. Half of the PR is tests. I agree that we want to keep the abstract layer to not get too bloated. Any alternative implementation ideas?

@travisofthenorth
Copy link
Contributor Author

@matthewd it seemed unavoidable but it was my first time digging into the adapter code so I could be wrong. I'm happy to make changes so let me know if you have any ideas.

@travisofthenorth
Copy link
Contributor Author

@matthewd I took another look at it. The latest commit moves most of the implementation into postgres-specific classes. I left some code in the ForeignKeyDefinition struct in abstract because it felt weird re-implementing that. Let me know how it looks now.

@travisofthenorth travisofthenorth force-pushed the validate-foreign-keys branch 5 times, most recently from 03fc5b4 to 53cbda5 Compare September 2, 2017 21:09
@travisofthenorth
Copy link
Contributor Author

Rebased on master and squashed to 1 commit. @matthewd please advise if you want to see any more changes in this PR, otherwise I think it should be good to go.

@travisofthenorth travisofthenorth force-pushed the validate-foreign-keys branch 2 times, most recently from ccdff49 to 171ba30 Compare September 25, 2017 23:25
Add validate_constraint and update naming
@travisofthenorth
Copy link
Contributor Author

@kamipo @matthewd just rebased on master. Any chance this could make it into 5.2?

@matthewd matthewd merged commit 9f33a8f into rails:master Dec 1, 2017
@matthewd
Copy link
Member

matthewd commented Dec 1, 2017

Sorry I didn't come back to this sooner, especially after you did a great job of addressing my concern about the split between abstract vs postgres adapters. 👍🏻

@travisofthenorth travisofthenorth deleted the validate-foreign-keys branch December 1, 2017 16:54
#
# Validates the constraint named +constraint_name+ on +accounts+.
#
# validate_foreign_key :accounts, :constraint_name
Copy link

Choose a reason for hiding this comment

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

This comment doesn't match the method it's documenting.

Copy link
Contributor

Choose a reason for hiding this comment

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

It was fixed by 70c96b4

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

Successfully merging this pull request may close these issues.

8 participants