Add created_at and updated_at columns to ft_notification_status

Added created_at and updated_at to the ft_notification_status table in order
to make it easier to track down any potential issues with the data.

Also updated the command to populate the data to take created_at and
updated_at into account and to simplify the command. This can all be done in
the same commit since the table is not being used anywhere yet and can
only be populated manually.
This commit is contained in:
Katie Smith
2018-05-22 16:25:07 +01:00
parent 369865cd82
commit 4d27972c90
3 changed files with 41 additions and 21 deletions

View File

@@ -618,30 +618,25 @@ def migrate_data_to_ft_notification_status(start_date, end_date):
sql = \
"""
insert into ft_notification_status (bst_date, template_id, service_id, job_id, notification_type, key_type,
notification_status, notification_count)
select bst_date, template_id, service_id, job_id, notification_type, key_type, notification_status,
sum(notification_count) as notification_count
from (
select
da.bst_date,
n.template_id,
n.service_id,
coalesce(n.job_id, '00000000-0000-0000-0000-000000000000') as job_id,
n.notification_type,
n.key_type,
n.notification_status,
1 as notification_count
from public.notification_history n
left join dm_datetime da on n.created_at >= da.utc_daytime_start
and n.created_at < da.utc_daytime_end
where n.created_at >= (date :start + time '00:00:00') at time zone 'Europe/London'
at time zone 'UTC'
and n.created_at < (date :end + time '00:00:00') at time zone 'Europe/London' at time zone 'UTC'
) as individual_record
notification_status, created_at, notification_count)
select
(n.created_at at time zone 'UTC' at time zone 'Europe/London')::timestamp::date as bst_date,
n.template_id,
n.service_id,
coalesce(n.job_id, '00000000-0000-0000-0000-000000000000') as job_id,
n.notification_type,
n.key_type,
n.notification_status,
now() as created_at,
count(*) as notification_count
from notification_history n
where n.created_at >= (date :start + time '00:00:00') at time zone 'Europe/London' at time zone 'UTC'
and n.created_at < (date :end + time '00:00:00') at time zone 'Europe/London' at time zone 'UTC'
group by bst_date, template_id, service_id, job_id, notification_type, key_type, notification_status
order by bst_date
on conflict on constraint ft_notification_status_pkey do update set
notification_count = excluded.notification_count
notification_count = excluded.notification_count,
updated_at = now()
"""
result = db.session.execute(sql, {"start": process_date, "end": process_date + timedelta(days=1)})
db.session.commit()

View File

@@ -1812,3 +1812,5 @@ class FactNotificationStatus(db.Model):
key_type = db.Column(db.Text, primary_key=True, nullable=False)
notification_status = db.Column(db.Text, primary_key=True, nullable=False)
notification_count = db.Column(db.Integer(), nullable=False)
created_at = db.Column(db.DateTime, nullable=False, default=datetime.datetime.utcnow)
updated_at = db.Column(db.DateTime, nullable=True, onupdate=datetime.datetime.utcnow)