Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Browse files

[bug 623961] Switch to SQL-based migrations for notifications.

  • Loading branch information...
commit ddb35fc183b57253a2033b34bbdf434c88529a43 1 parent 2cd2f00
@erikrose erikrose authored
View
0  apps/notifications/management/__init__.py
No changes.
View
0  apps/notifications/management/commands/__init__.py
No changes.
View
98 apps/notifications/management/commands/migrate_watches.py
@@ -1,98 +0,0 @@
-from django.contrib.auth.models import User
-from django.contrib.contenttypes.models import ContentType
-from django.core.management.base import BaseCommand
-from django.db import transaction
-
-from forums.events import NewPostEvent, NewThreadEvent
-from forums.models import Forum, Thread
-from kbforums.events import (NewPostEvent as KBNewPostEvent,
- NewThreadEvent as KBNewThreadEvent)
-from kbforums.models import Thread as KBThread
-from notifications.models import EventWatch
-from questions.events import QuestionReplyEvent, QuestionSolvedEvent
-from questions.models import Question
-from wiki.events import (EditDocumentEvent, ReviewableRevisionInLocaleEvent,
- ApproveRevisionInLocaleEvent)
-from wiki.models import Document
-
-
-# Not using sumo.utils.chunked so I can be smarter about calculating the
-# length of a QuerySet.
-def chunked(qs, n):
- """Yield successive n-sized chunks from QuerySet qs."""
- length = qs.count()
- for i in xrange(0, length, n):
- yield qs[i:i + n]
-
-
-# Either a user associated with an email address or the email address.
-def user_or_email(email):
- try:
- return User.objects.get(email=email)
- except User.MultipleObjectsReturned:
- # Pick the first one, note that this can't happen.
- u = User.objects.filter(email=email)
- print '%s had a duplicate email address.' % email
- return u[0]
- except User.DoesNotExist:
- return email
-
-
-# Migrate instance watches for `cls` from old EventWatches to `evt`.
-def migrate_instance_watches(watches, cls, evt):
- """Migrate a list of watches from a given cls to a new evt."""
- for watch in watches:
- # If there's a User with that email, use it, else use the
- # email address.
- who = user_or_email(watch.email)
- # Get the item being watched, else skip it, as stale.
- try:
- what = cls.objects.get(pk=watch.watch_id)
- except cls.DoesNotExist:
- continue
- evt.notify(who, what)
-
-
-class Command(BaseCommand):
- help = 'Migrate old EventWatches into the new system.'
-
- def handle(self, *args, **kwargs):
- transaction.enter_transaction_management(True)
-
- # Map EventWatches for a specific instance and type to the new
- # InstanceEvent subclass.
- mapping = (
- ('reply', QuestionReplyEvent, Question),
- ('solution', QuestionSolvedEvent, Question),
- ('post', KBNewThreadEvent, Document),
- ('edited', EditDocumentEvent, Document),
- ('post', NewThreadEvent, Forum),
- ('reply', NewPostEvent, Thread),
- ('reply', KBNewPostEvent, KBThread),
- )
- for type, evt, model in mapping:
- ct = ContentType.objects.get_for_model(model)
- print u'Migrating %s %s to %s...' % (model, type, evt)
- watches = ct.eventwatch_set.filter(event_type=type).order_by('id')
- # Chunking because there are nearly 200k for some of these.
- for i, chunk in enumerate(chunked(watches, 2000)):
- print u' Chunk %s' % i
- migrate_instance_watches(chunk, model, evt)
- transaction.commit()
-
- # Map locale-wide EventWatches to the new Event subclass.
- mapping = (
- ('approved', ApproveRevisionInLocaleEvent),
- ('ready_for_review', ReviewableRevisionInLocaleEvent),
- )
- ct = ContentType.objects.get_for_model(Document)
- for type, evt in mapping:
- print u'Migrating %s to %s...' % (type, evt)
- watches = ct.eventwatch_set.filter(event_type=type).order_by('id')
- # Not chunking because there are literally 30 of these.
- for watch in watches:
- who = user_or_email(watch.email)
- evt.notify(who, locale=watch.locale)
- transaction.commit()
-
- transaction.leave_transaction_management()
View
145 migrations/82-migrate-notifications.sql
@@ -0,0 +1,145 @@
+-- Migrate watches from the old notifications_eventwatch table to the 2 new ones.
+-- Took 2 minutes and 45 seconds for 120K rows on my laptop.
+
+-- First, frob the collation of the email column to hugely speed things up:
+ALTER TABLE notifications_watch MODIFY email varchar(75) NOT NULL COLLATE utf8_unicode_ci;
+BEGIN; -- MySQL stupidly commits when it hits an ALTER statement.
+
+-- Next, do the filterless watches:
+
+INSERT INTO notifications_watch
+ (event_type, content_type_id, object_id, is_active, email)
+ SELECT 'question solved',
+ content_type_id,
+ watch_id,
+ 1,
+ email
+ FROM notifications_eventwatch
+ WHERE event_type='solution';
+
+INSERT INTO notifications_watch
+ (event_type, content_type_id, object_id, is_active, email)
+ SELECT 'wiki edit document',
+ content_type_id,
+ watch_id,
+ 1,
+ email
+ FROM notifications_eventwatch
+ WHERE event_type='edited';
+
+-- 'post' type referring to wiki docs:
+INSERT INTO notifications_watch
+ (event_type, content_type_id, object_id, is_active, email)
+ SELECT 'kbforum thread',
+ content_type_id,
+ watch_id,
+ 1,
+ email
+ FROM notifications_eventwatch
+ WHERE event_type='post' AND content_type_id=(SELECT id from django_content_type where model='document' and app_label='wiki');
+
+-- 'post' type referring to forums:
+INSERT INTO notifications_watch
+ (event_type, content_type_id, object_id, is_active, email)
+ SELECT 'forum thread',
+ content_type_id,
+ watch_id,
+ 1,
+ email
+ FROM notifications_eventwatch
+ WHERE event_type='post' AND content_type_id=(SELECT id from django_content_type where model='forum' and app_label='forums');
+
+-- 'reply' type referring to questions:
+INSERT INTO notifications_watch
+ (event_type, content_type_id, object_id, is_active, email)
+ SELECT 'question reply',
+ content_type_id,
+ watch_id,
+ 1,
+ email
+ FROM notifications_eventwatch
+ WHERE event_type='reply' AND content_type_id=(SELECT id from django_content_type where model='question' and app_label='questions');
+
+-- 'reply' type referring to forum threads:
+INSERT INTO notifications_watch
+ (event_type, content_type_id, object_id, is_active, email)
+ SELECT 'thread reply',
+ content_type_id,
+ watch_id,
+ 1,
+ email
+ FROM notifications_eventwatch
+ WHERE event_type='reply' AND content_type_id=(SELECT id from django_content_type where model='thread' and app_label='forums');
+
+-- 'reply' type referring to kbforums:
+INSERT INTO notifications_watch
+ (event_type, content_type_id, object_id, is_active, email)
+ SELECT 'kbthread reply',
+ content_type_id,
+ watch_id,
+ 1,
+ email
+ FROM notifications_eventwatch
+ WHERE event_type='reply' AND content_type_id=(SELECT id from django_content_type where model='thread' and app_label='kbforums');
+
+
+-- Migrate watches that in the new system have filters:
+
+-- 'approved' type:
+-- We do a little dance where we stick the old watch ID into the object_id
+-- column temporarily and use it to find the old watch when inserting the new
+-- watchfilter row.
+INSERT INTO notifications_watch (event_type, is_active, email, object_id)
+ SELECT 'approved wiki in locale',
+ 1,
+ email,
+ id
+ FROM notifications_eventwatch
+ WHERE event_type='approved';
+INSERT INTO notifications_watchfilter (watch_id, name, value)
+ SELECT notifications_watch.id,
+ 'locale',
+ crc32(notifications_eventwatch.locale)
+ FROM notifications_watch
+ INNER JOIN notifications_eventwatch ON notifications_watch.object_id=notifications_eventwatch.id
+ WHERE notifications_eventwatch.event_type='approved';
+UPDATE notifications_watch SET object_id=NULL
+ WHERE event_type='approved wiki in locale';
+
+-- 'ready_for_review' type:
+INSERT INTO notifications_watch (event_type, is_active, email, object_id)
+ SELECT 'reviewable wiki in locale',
+ 1,
+ email,
+ id
+ FROM notifications_eventwatch
+ WHERE event_type='ready_for_review';
+INSERT INTO notifications_watchfilter (watch_id, name, value)
+ SELECT notifications_watch.id,
+ 'locale',
+ crc32(notifications_eventwatch.locale)
+ FROM notifications_watch
+ INNER JOIN notifications_eventwatch ON notifications_watch.object_id=notifications_eventwatch.id
+ WHERE notifications_eventwatch.event_type='ready_for_review';
+UPDATE notifications_watch SET object_id=NULL
+ WHERE event_type='reviewable wiki in locale';
+
+
+-- Replace the emails with user IDs where they match:
+UPDATE notifications_watch INNER JOIN auth_user ON notifications_watch.email=auth_user.email SET notifications_watch.user_id=auth_user.id, notifications_watch.email=NULL;
+-- And put the email column's collation back the way we found it:
+ALTER TABLE notifications_watch MODIFY email varchar(75) NOT NULL COLLATE utf8_general_ci;
+
+
+-- Insert random secrets:
+UPDATE notifications_watch SET secret=concat(
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)),
+ char(round(rand() * 25) + (case when round(rand()) then 65 else 97 end)));
View
5 push.txt
@@ -15,8 +15,3 @@ This Time
=========
1. Update Sphinx config.
-2. Migrate watches:
-2.1. Set CONFIRM_ANONYMOUS_WATCHES = False in settings_local.py
-2.2. manage.py migrate_watches # may take a while
-2.3. Set CONFIRM_ANONYMOUS_WATCHES = True (or comment out = False)
-
Please sign in to comment.
Something went wrong with that request. Please try again.