Skip to content
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

add column to packages for current_serial, as well as trigger on journal... #195

Closed
wants to merge 5 commits into from
Closed
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
Original file line number Diff line number Diff line change
@@ -0,0 +1,68 @@
# Copyright 2013 Donald Stufft
#
# Licensed under the Apache License, Version 2.0 (the "License");
# you may not use this file except in compliance with the License.
# You may obtain a copy of the License at
#
# http://www.apache.org/licenses/LICENSE-2.0
#
# Unless required by applicable law or agreed to in writing, software
# distributed under the License is distributed on an "AS IS" BASIS,
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
# See the License for the specific language governing permissions and
# limitations under the License.
"""
add current_serial and trigger for package journal

Revision ID: 55b028ee498d
Revises: 55eda9672691
Create Date: 2014-02-09 11:52:39.756097
"""
from __future__ import absolute_import, division, print_function

# revision identifiers, used by Alembic.
revision = '55b028ee498d'
down_revision = '55eda9672691'

from alembic import op
import sqlalchemy as sa
from sqlalchemy.dialects import postgresql

def upgrade():
op.add_column(
"packages",
sa.Column("current_serial", sa.INTEGER, nullable=True),
)
op.execute("""
CREATE OR REPLACE FUNCTION update_packages_current_serial() RETURNS TRIGGER
AS $journals$
BEGIN
UPDATE packages
SET current_serial = (SELECT MAX(id) FROM journals WHERE name = NEW.name);
RETURN NULL;
END;
$journals$
LANGUAGE 'plpgsql';
""")
op.execute("""
CREATE TRIGGER update_packages_current_serial
AFTER UPDATE OR INSERT ON journals
FOR EACH ROW
EXECUTE PROCEDURE update_packages_current_serial();
""")
op.execute("""
Copy link
Contributor

Choose a reason for hiding this comment

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

I wouldn't apply this as a part of the migration. I'd recommend doing this as a backfill on all columns that are NULL later.

Copy link
Member Author

Choose a reason for hiding this comment

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

ahhh, the NULL check should be part of this command regardless.

Copy link
Contributor

Choose a reason for hiding this comment

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

Yeah, I'd just separate this data migration from the schema migration personally. Since this is going to just update 40k rows. Everything else is non-blocking.

Copy link
Member Author

Choose a reason for hiding this comment

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

i'd approximate the update to block for only 20 to 30 seconds based on benchmarks for the select i performed last night.

Copy link
Contributor

Choose a reason for hiding this comment

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

That's fine. We can do this with 0 blocking though. :) But the downtime is your call. I also, out of principal, like to keep data and schema migrations separately. The schema migration here is safe to apply at any time, and you'd want to more-or-less, schedule the data migration or run it offline, etc. Again, not sure how things are set upw tih pypi or how things are typically done. Just my 2 cents.

Copy link
Member Author

Choose a reason for hiding this comment

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

the migration is going to run in a transaction, so there are two things i think i can confidently say:

  • NULL check is good practice, but shouldn't be necessary
  • calls to the packages table in the meantime will just wait for the transaction to finish, so downtime shouldn't be necessary.

Copy link
Contributor

Choose a reason for hiding this comment

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

Well, if that's a risk you're willing to take, then I'd just do this all in one shot and remove the nullable constraint at the end. Or just set a default and let it block while writing the column.

I only suggested making it nullable assuming a data migration "at some point in the future".

UPDATE packages
SET current_serial = (SELECT MAX(id) FROM journals WHERE name = packages.name)
WHERE current_serial IS NULL;
""")

def downgrade():
op.execute("""
DROP TRIGGER update_packages_current_serial ON journals;
""")
op.execute("""
DROP FUNCTION update_packages_current_serial();
""")
op.drop_column(
"packages", "current_serial"
)