ogn-python/ogn/collect/logbook.py

160 wiersze
8.4 KiB
Python
Czysty Zwykły widok Historia

from celery.utils.log import get_task_logger
2016-06-29 21:26:30 +00:00
from sqlalchemy import and_, or_, insert, update, between, exists
2016-07-02 18:07:22 +00:00
from sqlalchemy.sql import func, null
2016-11-01 07:30:05 +00:00
from sqlalchemy.sql.expression import true, false
2015-11-11 07:04:42 +00:00
2016-07-02 18:07:22 +00:00
from ogn.collect.celery import app
from ogn.model import TakeoffLanding, Logbook
2015-11-11 07:04:42 +00:00
logger = get_task_logger(__name__)
2015-11-11 07:04:42 +00:00
2016-06-29 21:26:30 +00:00
@app.task
2017-12-10 16:30:27 +00:00
def update_logbook(session=None):
2016-06-29 21:26:30 +00:00
logger.info("Compute logbook.")
2016-07-02 18:07:22 +00:00
if session is None:
session = app.session
2016-06-29 21:26:30 +00:00
or_args = [between(TakeoffLanding.timestamp, '2016-06-28 00:00:00', '2016-06-28 23:59:59')]
or_args = []
# 'wo' is the window order for the sql window function
wo = and_(func.date(TakeoffLanding.timestamp),
TakeoffLanding.device_id,
TakeoffLanding.timestamp,
TakeoffLanding.airport_id)
2016-06-29 21:26:30 +00:00
# make a query with current, previous and next "takeoff_landing" event, so we can find complete flights
2016-07-02 18:07:22 +00:00
sq = session.query(
2016-07-01 05:19:31 +00:00
TakeoffLanding.device_id,
func.lag(TakeoffLanding.device_id).over(order_by=wo).label('device_id_prev'),
func.lead(TakeoffLanding.device_id).over(order_by=wo).label('device_id_next'),
TakeoffLanding.timestamp,
func.lag(TakeoffLanding.timestamp).over(order_by=wo).label('timestamp_prev'),
func.lead(TakeoffLanding.timestamp).over(order_by=wo).label('timestamp_next'),
TakeoffLanding.track,
func.lag(TakeoffLanding.track).over(order_by=wo).label('track_prev'),
func.lead(TakeoffLanding.track).over(order_by=wo).label('track_next'),
TakeoffLanding.is_takeoff,
func.lag(TakeoffLanding.is_takeoff).over(order_by=wo).label('is_takeoff_prev'),
func.lead(TakeoffLanding.is_takeoff).over(order_by=wo).label('is_takeoff_next'),
TakeoffLanding.airport_id,
func.lag(TakeoffLanding.airport_id).over(order_by=wo).label('airport_id_prev'),
func.lead(TakeoffLanding.airport_id).over(order_by=wo).label('airport_id_next')) \
2016-06-29 21:26:30 +00:00
.filter(*or_args) \
.subquery()
# find complete flights (with takeoff and landing on the same day)
2016-07-02 18:07:22 +00:00
complete_flight_query = session.query(
2016-06-29 21:26:30 +00:00
sq.c.timestamp.label('reftime'),
sq.c.device_id.label('device_id'),
2016-06-30 20:43:09 +00:00
sq.c.timestamp.label('takeoff_timestamp'), sq.c.track.label('takeoff_track'), sq.c.airport_id.label('takeoff_airport_id'),
sq.c.timestamp_next.label('landing_timestamp'), sq.c.track_next.label('landing_track'), sq.c.airport_id_next.label('landing_airport_id')) \
2016-06-29 21:26:30 +00:00
.filter(and_(sq.c.is_takeoff == true(), sq.c.is_takeoff_next == false())) \
.filter(sq.c.device_id == sq.c.device_id_next) \
.filter(func.date(sq.c.timestamp_next) == func.date(sq.c.timestamp))
# split complete flights (with takeoff and landing on different days) into one takeoff and one landing
2016-07-02 18:07:22 +00:00
split_start_query = session.query(
2016-06-29 21:26:30 +00:00
sq.c.timestamp.label('reftime'),
sq.c.device_id.label('device_id'),
2016-06-30 20:43:09 +00:00
sq.c.timestamp.label('takeoff_timestamp'), sq.c.track.label('takeoff_track'), sq.c.airport_id.label('takeoff_airport_id'),
null().label('landing_timestamp'), null().label('landing_track'), null().label('landing_airport_id')) \
2016-06-29 21:26:30 +00:00
.filter(and_(sq.c.is_takeoff == true(), sq.c.is_takeoff_next == false())) \
.filter(sq.c.device_id == sq.c.device_id_next) \
.filter(func.date(sq.c.timestamp_next) != func.date(sq.c.timestamp))
2016-07-02 18:07:22 +00:00
split_landing_query = session.query(
2016-06-29 21:26:30 +00:00
sq.c.timestamp_next.label('reftime'),
sq.c.device_id.label('device_id'),
2016-06-30 20:43:09 +00:00
null().label('takeoff_timestamp'), null().label('takeoff_track'), null().label('takeoff_airport_id'),
sq.c.timestamp_next.label('landing_timestamp'), sq.c.track_next.label('landing_track'), sq.c.airport_id_next.label('landing_airport_id')) \
2016-06-29 21:26:30 +00:00
.filter(and_(sq.c.is_takeoff == true(), sq.c.is_takeoff_next == false())) \
.filter(sq.c.device_id == sq.c.device_id_next) \
.filter(func.date(sq.c.timestamp_next) != func.date(sq.c.timestamp))
# find landings without start
2016-07-02 18:07:22 +00:00
only_landings_query = session.query(
2016-06-29 21:26:30 +00:00
sq.c.timestamp.label('reftime'),
sq.c.device_id.label('device_id'),
2016-06-30 20:43:09 +00:00
null().label('takeoff_timestamp'), null().label('takeoff_track'), null().label('takeoff_airport_id'),
sq.c.timestamp.label('landing_timestamp'), sq.c.track.label('landing_track'), sq.c.airport_id.label('landing_airport_id')) \
2016-06-29 21:26:30 +00:00
.filter(sq.c.is_takeoff == false()) \
.filter(or_(sq.c.device_id != sq.c.device_id_prev,
2016-07-02 14:31:33 +00:00
sq.c.is_takeoff_prev == false(),
sq.c.is_takeoff_prev == null()))
2016-06-29 21:26:30 +00:00
# find starts without landing
2016-07-02 18:07:22 +00:00
only_starts_query = session.query(
2016-06-29 21:26:30 +00:00
sq.c.timestamp.label('reftime'),
sq.c.device_id.label('device_id'),
2016-06-30 20:43:09 +00:00
sq.c.timestamp.label('takeoff_timestamp'), sq.c.track.label('takeoff_track'), sq.c.airport_id.label('takeoff_airport_id'),
null().label('landing_timestamp'), null().label('landing_track'), null().label('landing_airport_id')) \
2016-06-29 21:26:30 +00:00
.filter(sq.c.is_takeoff == true()) \
.filter(or_(sq.c.device_id != sq.c.device_id_next,
2016-07-02 14:31:33 +00:00
sq.c.is_takeoff_next == true(),
sq.c.is_takeoff_next == null()))
2016-06-29 21:26:30 +00:00
2016-07-06 17:34:55 +00:00
# unite all computated flights
union_query = complete_flight_query.union(
split_start_query,
split_landing_query,
only_landings_query,
only_starts_query) \
.subquery()
2016-06-30 20:43:09 +00:00
2016-07-06 17:34:55 +00:00
# if a logbook entry exist --> update it
2016-06-30 20:43:09 +00:00
upd = update(Logbook) \
2016-07-06 17:34:55 +00:00
.where(and_(Logbook.device_id == union_query.c.device_id,
union_query.c.takeoff_airport_id != null(),
union_query.c.landing_airport_id != null(),
or_(and_(Logbook.takeoff_airport_id == union_query.c.takeoff_airport_id,
Logbook.takeoff_timestamp == union_query.c.takeoff_timestamp,
2016-07-04 20:54:37 +00:00
Logbook.landing_airport_id == null()),
and_(Logbook.takeoff_airport_id == null(),
2016-07-06 17:34:55 +00:00
Logbook.landing_airport_id == union_query.c.landing_airport_id,
Logbook.landing_timestamp == union_query.c.landing_timestamp)))) \
.values({"takeoff_timestamp": union_query.c.takeoff_timestamp,
"takeoff_track": union_query.c.takeoff_track,
"takeoff_airport_id": union_query.c.takeoff_airport_id,
"landing_timestamp": union_query.c.landing_timestamp,
"landing_track": union_query.c.landing_track,
"landing_airport_id": union_query.c.landing_airport_id})
2016-06-30 20:43:09 +00:00
2016-07-02 18:07:22 +00:00
result = session.execute(upd)
2016-07-04 20:54:37 +00:00
update_counter = result.rowcount
2016-07-02 18:07:22 +00:00
session.commit()
2016-07-04 20:54:37 +00:00
logger.debug("Updated logbook entries: {}".format(update_counter))
2016-06-30 20:43:09 +00:00
2016-07-06 17:34:55 +00:00
# if a logbook entry doesnt exist --> insert it
2016-07-02 18:07:22 +00:00
new_logbook_entries = session.query(union_query) \
2016-06-29 21:26:30 +00:00
.filter(~exists().where(
2016-07-04 20:54:37 +00:00
and_(Logbook.device_id == union_query.c.device_id,
or_(and_(Logbook.takeoff_airport_id == union_query.c.takeoff_airport_id,
Logbook.takeoff_timestamp == union_query.c.takeoff_timestamp),
2016-06-29 21:26:30 +00:00
and_(Logbook.takeoff_airport_id == null(),
union_query.c.takeoff_airport_id == null())),
2016-07-04 20:54:37 +00:00
or_(and_(Logbook.landing_airport_id == union_query.c.landing_airport_id,
Logbook.landing_timestamp == union_query.c.landing_timestamp),
2016-06-29 21:26:30 +00:00
and_(Logbook.landing_airport_id == null(),
union_query.c.landing_airport_id == null())))))
ins = insert(Logbook).from_select((Logbook.reftime,
Logbook.device_id,
Logbook.takeoff_timestamp,
Logbook.takeoff_track,
Logbook.takeoff_airport_id,
Logbook.landing_timestamp,
Logbook.landing_track,
Logbook.landing_airport_id),
2016-06-29 21:26:30 +00:00
new_logbook_entries)
2016-07-02 18:07:22 +00:00
result = session.execute(ins)
2016-07-04 20:54:37 +00:00
insert_counter = result.rowcount
2016-07-02 18:07:22 +00:00
session.commit()
2016-07-04 20:54:37 +00:00
logger.debug("New logbook entries: {}".format(insert_counter))
2016-06-29 21:26:30 +00:00
2016-07-04 20:54:37 +00:00
return "{}/{}".format(update_counter, insert_counter)