diff --git a/README.md b/README.md index e22e17a..2215458 100644 --- a/README.md +++ b/README.md @@ -6,7 +6,7 @@ A database backend for the [Open Glider Network](http://wiki.glidernet.org/). The ogn-python module saves all received beacons into a database with [SQLAlchemy](http://www.sqlalchemy.org/). It connects to the OGN aprs servers with [python-ogn-client](https://github.com/glidernet/python-ogn-client). -It requires [PostgreSQL](http://www.postgresql.org/), [PostGIS](http://www.postgis.net/) and [TimescaleDB](https://www.timescale.com). +It requires [redis](http://redis.io), [PostgreSQL](http://www.postgresql.org/), [PostGIS](http://www.postgis.net/) and [TimescaleDB](https://www.timescale.com). [Examples](https://github.com/glidernet/ogn-python/wiki/Examples) @@ -156,23 +156,25 @@ Most commands are command groups, so if you execute this command you will get fu ### Available tasks +- `app.tasks.transfer_to_database` - Take sender and receiver messages from redis and put them into the db. - `app.tasks.update_takeoff_landings` - Compute takeoffs and landings. -- `app.tasks.celery.update_logbook_entries` - Add/update logbook entries. -- `app.tasks.celery.update_logbook_max_altitude` - Add max altitudes in logbook when flight is complete (takeoff and landing). -- `app.tasks.celery.import_ddb` - Import registered devices from the DDB. +- `app.tasks.update_logbook` - Add/update logbook entries. +- `app.tasks.update_logbook_max_altitude` - Add max altitudes in logbook when flight is complete (takeoff and landing). +- `app.tasks.update_statistics` - Calculate several statistics (also the sender/receiver rankings). +- `app.tasks.import_ddb` - Import registered devices from the DDB. If the task server is up and running, tasks could be started manually. Here we compute takeoffs and landings for the past 90 minutes: ``` python3 ->>>from app.collect.celery import update_takeoff_landings +>>>from app.tasks import update_takeoff_landings >>>update_takeoff_landings.delay(last_minutes=90) ``` or directly from command line: ``` -celery -A celery_app call takeoff_landings +celery -A celery_app call import_ddb ``` ## Notes for Raspberry Pi diff --git a/app/gateway/message_handling.py b/app/gateway/message_handling.py index 40f11b4..048e807 100644 --- a/app/gateway/message_handling.py +++ b/app/gateway/message_handling.py @@ -251,7 +251,7 @@ def sender_position_csv_strings_to_db(lines): # Update coverage statistics cursor.execute(f""" - INSERT INTO coverage_statistics AS rs (date, location_mgrs_short, sender_id, receiver_id, is_trustworthy, max_distance, max_normalized_quality, messages_count) + INSERT INTO coverage_statistics AS rs (date, location_mgrs_short, sender_id, receiver_id, is_trustworthy, max_distance, max_normalized_quality, max_signal_quality, min_altitude, max_altitude, messages_count) SELECT tmp.reference_timestamp::DATE AS date, tmp.location_mgrs_short, @@ -262,6 +262,9 @@ def sender_position_csv_strings_to_db(lines): MAX(tmp.distance) AS max_distance, MAX(tmp.normalized_quality) AS max_normalized_quality, + MAX(tmp.signal_quality) AS max_signal_quality, + MIN(tmp.altitude) AS min_altitude, + MAX(tmp.altitude) AS max_altitude, COUNT(tmp.*) AS messages_count FROM (SELECT x.*, s.id AS sender_id, r.id AS receiver_id FROM {tmp_tablename} AS x INNER JOIN senders AS s ON x.name = s.name INNER JOIN receivers AS r ON x.receiver_name = r.name) AS tmp GROUP BY date, location_mgrs_short, sender_id, receiver_id, is_trustworthy diff --git a/app/main/matplotlib_service.py b/app/main/matplotlib_service.py index 7b4cf54..12e488a 100644 --- a/app/main/matplotlib_service.py +++ b/app/main/matplotlib_service.py @@ -1,5 +1,5 @@ from app import db -from app.model import SenderDirectionStatistic +from app.model import DirectionStatistic import random import numpy as np import matplotlib.pyplot as plt @@ -17,9 +17,9 @@ def create_range_figure2(sender_id): def create_range_figure(sender_id): - sds = db.session.query(SenderDirectionStatistic) \ - .filter(SenderDirectionStatistic.sender_id == sender_id) \ - .order_by(SenderDirectionStatistic.directions_count.desc()) \ + sds = db.session.query(DirectionStatistic) \ + .filter(DirectionStatistic.sender_id == sender_id) \ + .order_by(DirectionStatistic.directions_count.desc()) \ .limit(1) \ .one() diff --git a/app/main/routes.py b/app/main/routes.py index 70cfea1..7e9733f 100644 --- a/app/main/routes.py +++ b/app/main/routes.py @@ -2,12 +2,12 @@ import os import re from datetime import date, time, datetime, timedelta -from flask import request, render_template, send_file, abort, current_app, make_response +from flask import request, render_template, abort, current_app, make_response, jsonify from sqlalchemy.orm.exc import NoResultFound from app import db from app import cache -from app.model import Airport, Country, Sender, SenderInfo, TakeoffLanding, Logbook, Receiver, SenderPosition, RelationStatistic, ReceiverRanking, ReceiverStatistic, SenderStatistic, FrequencyScanFile +from app.model import Airport, Country, CoverageStatistic, AggregateCoverageStatistic, Sender, TakeoffLanding, Logbook, Receiver, ReceiverRanking, ReceiverStatistic, SenderStatistic, FrequencyScanFile from app.main import bp from app.main.matplotlib_service import create_range_figure diff --git a/app/model/__init__.py b/app/model/__init__.py index e71d07f..0f4ba79 100644 --- a/app/model/__init__.py +++ b/app/model/__init__.py @@ -16,11 +16,15 @@ from .frequency_scan_file import FrequencyScanFile from .geo import Location -from .relation_statistic import RelationStatistic +from .direction_statistic import DirectionStatistic + from .coverage_statistic import CoverageStatistic +from .receiver_coverage_statistic import ReceiverCoverageStatistic +from .sender_coverage_statistic import SenderCoverageStatistic +from .aggregate_coverage_statistic import AggregateCoverageStatistic + from .sender_statistic import SenderStatistic from .receiver_statistic import ReceiverStatistic from .sender_position_statistic import SenderPositionStatistic -from .sender_direction_statistic import SenderDirectionStatistic from .receiver_ranking import ReceiverRanking from .receiver_status_statistic import ReceiverStatusStatistic diff --git a/app/model/aggregate_coverage_statistic.py b/app/model/aggregate_coverage_statistic.py new file mode 100644 index 0000000..a182d48 --- /dev/null +++ b/app/model/aggregate_coverage_statistic.py @@ -0,0 +1,22 @@ +from app import db + + +class AggregateCoverageStatistic(db.Model): + __tablename__ = "aggregate_coverage_statistics" + + id = db.Column(db.Integer, primary_key=True) + + date = db.Column(db.Date) + location_mgrs_short = db.Column(db.String(9)) + is_trustworthy = db.Column(db.Boolean) + + messages_count = db.Column(db.Integer) + max_distance = db.Column(db.Float(precision=2)) + max_normalized_quality = db.Column(db.Float(precision=2)) + max_signal_quality = db.Column(db.Float(precision=2)) + min_altitude = db.Column(db.Float(precision=2)) + max_altitude = db.Column(db.Float(precision=2)) + senders_count = db.Column(db.Integer) + receivers_count = db.Column(db.Integer) + + __table_args__ = (db.Index('idx_aggregate_coverage_statistics_uc', 'date', 'location_mgrs_short', 'is_trustworthy', unique=True), ) diff --git a/app/model/coverage_statistic.py b/app/model/coverage_statistic.py index 8fa39d9..e0e5664 100644 --- a/app/model/coverage_statistic.py +++ b/app/model/coverage_statistic.py @@ -13,7 +13,9 @@ class CoverageStatistic(db.Model): messages_count = db.Column(db.Integer) max_distance = db.Column(db.Float(precision=2)) max_normalized_quality = db.Column(db.Float(precision=2)) - coverages_count = db.Column(db.Integer) + max_signal_quality = db.Column(db.Float(precision=2)) + min_altitude = db.Column(db.Float(precision=2)) + max_altitude = db.Column(db.Float(precision=2)) # Relations sender_id = db.Column(db.Integer, db.ForeignKey("senders.id", ondelete="CASCADE"), index=True) diff --git a/app/model/sender_direction_statistic.py b/app/model/direction_statistic.py similarity index 78% rename from app/model/sender_direction_statistic.py rename to app/model/direction_statistic.py index d468989..4ab77da 100644 --- a/app/model/sender_direction_statistic.py +++ b/app/model/direction_statistic.py @@ -3,8 +3,8 @@ from app import db from sqlalchemy.dialects.postgresql import JSON -class SenderDirectionStatistic(db.Model): - __tablename__ = "sender_direction_statistics" +class DirectionStatistic(db.Model): + __tablename__ = "direction_statistics" id = db.Column(db.Integer, primary_key=True) @@ -19,4 +19,4 @@ class SenderDirectionStatistic(db.Model): receiver_id = db.Column(db.Integer, db.ForeignKey("receivers.id", ondelete="CASCADE"), index=True) receiver = db.relationship("Receiver", foreign_keys=[receiver_id], backref=db.backref("direction_stats", order_by=directions_count.desc())) - __table_args__ = (db.Index('idx_sender_direction_statistics_uc', 'sender_id', 'receiver_id', unique=True), ) + __table_args__ = (db.Index('idx_direction_statistics_uc', 'sender_id', 'receiver_id', unique=True), ) diff --git a/app/model/receiver_coverage_statistic.py b/app/model/receiver_coverage_statistic.py new file mode 100644 index 0000000..6f8c4a3 --- /dev/null +++ b/app/model/receiver_coverage_statistic.py @@ -0,0 +1,25 @@ +from app import db + + +class ReceiverCoverageStatistic(db.Model): + __tablename__ = "receiver_coverage_statistics" + + id = db.Column(db.Integer, primary_key=True) + + date = db.Column(db.Date) + location_mgrs_short = db.Column(db.String(9)) + is_trustworthy = db.Column(db.Boolean) + + messages_count = db.Column(db.Integer) + max_distance = db.Column(db.Float(precision=2)) + max_normalized_quality = db.Column(db.Float(precision=2)) + max_signal_quality = db.Column(db.Float(precision=2)) + min_altitude = db.Column(db.Float(precision=2)) + max_altitude = db.Column(db.Float(precision=2)) + senders_count = db.Column(db.Integer) + + # Relations + receiver_id = db.Column(db.Integer, db.ForeignKey("receivers.id", ondelete="CASCADE"), index=True) + receiver = db.relationship("Receiver", foreign_keys=[receiver_id], backref=db.backref("receiver_coverage_stats", order_by=date)) + + __table_args__ = (db.Index('idx_receiver_coverage_statistics_uc', 'date', 'receiver_id', 'location_mgrs_short', 'is_trustworthy', unique=True), ) diff --git a/app/model/relation_statistic.py b/app/model/relation_statistic.py deleted file mode 100644 index 92dfeb6..0000000 --- a/app/model/relation_statistic.py +++ /dev/null @@ -1,23 +0,0 @@ -from app import db - - -class RelationStatistic(db.Model): - __tablename__ = "relation_statistics" - - id = db.Column(db.Integer, primary_key=True) - - date = db.Column(db.Date) - is_trustworthy = db.Column(db.Boolean) - - max_distance = db.Column(db.Float(precision=2)) - max_normalized_quality = db.Column(db.Float(precision=2)) - messages_count = db.Column(db.Integer) - - # Relations - sender_id = db.Column(db.Integer, db.ForeignKey("senders.id", ondelete="CASCADE"), index=True) - sender = db.relationship("Sender", foreign_keys=[sender_id], backref=db.backref("relation_stats", order_by=date)) - - receiver_id = db.Column(db.Integer, db.ForeignKey("receivers.id", ondelete="CASCADE"), index=True) - receiver = db.relationship("Receiver", foreign_keys=[receiver_id], backref=db.backref("relation_stats", order_by=date)) - - __table_args__ = (db.Index('idx_relation_statistics_uc', 'date', 'sender_id', 'receiver_id', 'is_trustworthy', unique=True), ) diff --git a/app/model/sender_coverage_statistic.py b/app/model/sender_coverage_statistic.py new file mode 100644 index 0000000..41fe62a --- /dev/null +++ b/app/model/sender_coverage_statistic.py @@ -0,0 +1,25 @@ +from app import db + + +class SenderCoverageStatistic(db.Model): + __tablename__ = "sender_coverage_statistics" + + id = db.Column(db.Integer, primary_key=True) + + date = db.Column(db.Date) + location_mgrs_short = db.Column(db.String(9)) + is_trustworthy = db.Column(db.Boolean) + + messages_count = db.Column(db.Integer) + max_distance = db.Column(db.Float(precision=2)) + max_normalized_quality = db.Column(db.Float(precision=2)) + max_signal_quality = db.Column(db.Float(precision=2)) + min_altitude = db.Column(db.Float(precision=2)) + max_altitude = db.Column(db.Float(precision=2)) + receivers_count = db.Column(db.Integer) + + # Relations + sender_id = db.Column(db.Integer, db.ForeignKey("senders.id", ondelete="CASCADE"), index=True) + sender = db.relationship("Sender", foreign_keys=[sender_id], backref=db.backref("sender_coverage_stats", order_by=date)) + + __table_args__ = (db.Index('idx_sender_coverage_statistics_uc', 'date', 'sender_id', 'location_mgrs_short', 'is_trustworthy', unique=True), ) diff --git a/app/tasks/sql_tasks.py b/app/tasks/sql_tasks.py index c4db06b..fa4dde1 100644 --- a/app/tasks/sql_tasks.py +++ b/app/tasks/sql_tasks.py @@ -5,31 +5,84 @@ from app import db, celery @celery.task(name="update_statistics") def update_statistics(date_str=None): - """ Update relation_statistics, sender_statistics, receiver_statistics (all depend on coverage_statistics).""" + """ Update sender_statistics, receiver_statistics (all depend on coverage_statistics).""" if date_str is None: date_str = datetime.utcnow().strftime("%Y-%m-%d") - # Update relation statistics + # Update sender_coverage_statistics AS scs (date, sender_id, location_mgrs_short, is_trustworthy, max_distance, max_normalized_quality, max_signal_quality, min_altitude, max_altitude, messages_count, receivers_count) db.session.execute(f""" - DELETE FROM relation_statistics + DELETE FROM sender_coverage_statistics WHERE date = '{date_str}'; - INSERT INTO relation_statistics AS rs (date, sender_id, receiver_id, is_trustworthy, max_distance, max_normalized_quality, messages_count, coverages_count) + INSERT INTO sender_coverage_statistics AS scs (date, sender_id, location_mgrs_short, is_trustworthy, max_distance, max_normalized_quality, max_signal_quality, min_altitude, max_altitude, messages_count, receivers_count) SELECT tmp.date, tmp.sender_id, - tmp.receiver_id, + tmp.location_mgrs_short, - is_trustworthy, + tmp.is_trustworthy, MAX(tmp.max_distance) AS max_distance, MAX(tmp.max_normalized_quality) AS max_normalized_quality, + MAX(tmp.max_signal_quality) AS max_signal_quality, + MIN(tmp.min_altitude) AS min_altitude, + MAX(tmp.max_altitude) AS max_altitude, SUM(tmp.messages_count) AS messages_count, - COUNT(DISTINCT tmp.location_mgrs_short) AS coverages_count + COUNT(DISTINCT tmp.receiver_id) AS receivers_count FROM coverage_statistics AS tmp WHERE tmp.date = '{date_str}' - GROUP BY date, sender_id, receiver_id, is_trustworthy; + GROUP BY date, sender_id, location_mgrs_short, is_trustworthy; + """) + + # Update receiver_coverage_statistics AS rcs (date, sender_id, location_mgrs_short, is_trustworthy, max_distance, max_normalized_quality, max_signal_quality, min_altitude, max_altitude, messages_count, senders_count) + db.session.execute(f""" + DELETE FROM receiver_coverage_statistics + WHERE date = '{date_str}'; + + INSERT INTO receiver_coverage_statistics AS rcs (date, receiver_id, location_mgrs_short, is_trustworthy, max_distance, max_normalized_quality, max_signal_quality, min_altitude, max_altitude, messages_count, senders_count) + SELECT + tmp.date, + tmp.receiver_id, + tmp.location_mgrs_short, + + tmp.is_trustworthy, + + MAX(tmp.max_distance) AS max_distance, + MAX(tmp.max_normalized_quality) AS max_normalized_quality, + MAX(tmp.max_signal_quality) AS max_signal_quality, + MIN(tmp.min_altitude) AS min_altitude, + MAX(tmp.max_altitude) AS max_altitude, + SUM(tmp.messages_count) AS messages_count, + COUNT(DISTINCT tmp.sender_id) AS senders_count + FROM coverage_statistics AS tmp + WHERE tmp.date = '{date_str}' + GROUP BY date, receiver_id, location_mgrs_short, is_trustworthy; + """) + + # Update aggregate_coverage_statistics AS rcs (date, location_mgrs_short, is_trustworthy, max_distance, max_normalized_quality, max_signal_quality, min_altitude, max_altitude, messages_count, senders_count, receivers_count) + db.session.execute(f""" + DELETE FROM aggregate_coverage_statistics + WHERE date = '{date_str}'; + + INSERT INTO aggregate_coverage_statistics AS rcs (date, location_mgrs_short, is_trustworthy, max_distance, max_normalized_quality, max_signal_quality, min_altitude, max_altitude, messages_count, senders_count, receivers_count) + SELECT + tmp.date, + tmp.location_mgrs_short, + + tmp.is_trustworthy, + + MAX(tmp.max_distance) AS max_distance, + MAX(tmp.max_normalized_quality) AS max_normalized_quality, + MAX(tmp.max_signal_quality) AS max_signal_quality, + MIN(tmp.min_altitude) AS min_altitude, + MAX(tmp.max_altitude) AS max_altitude, + SUM(tmp.messages_count) AS messages_count, + COUNT(DISTINCT tmp.sender_id) AS senders_count, + COUNT(DISTINCT tmp.receiver_id) AS receivers_count + FROM coverage_statistics AS tmp + WHERE tmp.date = '{date_str}' + GROUP BY date, location_mgrs_short, is_trustworthy; """) # Update sender statistics @@ -37,7 +90,7 @@ def update_statistics(date_str=None): DELETE FROM sender_statistics WHERE date = '{date_str}'; - INSERT INTO sender_statistics AS rs (date, sender_id, is_trustworthy, max_distance, max_normalized_quality, messages_count, coverages_count, receivers_count) + INSERT INTO sender_statistics AS ss (date, sender_id, is_trustworthy, max_distance, max_normalized_quality, messages_count, coverages_count, receivers_count) SELECT tmp.date, tmp.sender_id, diff --git a/app/utils.py b/app/utils.py index 968a054..a8d2aa4 100644 --- a/app/utils.py +++ b/app/utils.py @@ -86,12 +86,12 @@ def get_sql_trustworthy(source_table_alias): MIN_DISTANCE = 1000 MAX_DISTANCE = 640000 MAX_NORMALIZED_QUALITY = 40 # this is enough for > 640km - MAX_ERROR_COUNT = 5 + MAX_ERROR_COUNT = 9 MAX_CLIMB_RATE = 50 return f""" ({source_table_alias}.distance IS NOT NULL AND {source_table_alias}.distance BETWEEN {MIN_DISTANCE} AND {MAX_DISTANCE}) - AND ({source_table_alias}.normalized_quality IS NOT NULL AND {source_table_alias}.normalized_quality < {MAX_NORMALIZED_QUALITY}) - AND ({source_table_alias}.error_count IS NULL OR {source_table_alias}.error_count < {MAX_ERROR_COUNT}) + AND ({source_table_alias}.normalized_quality IS NOT NULL AND {source_table_alias}.normalized_quality <= {MAX_NORMALIZED_QUALITY}) + AND ({source_table_alias}.error_count IS NULL OR {source_table_alias}.error_count <= {MAX_ERROR_COUNT}) AND ({source_table_alias}.climb_rate IS NULL OR {source_table_alias}.climb_rate BETWEEN -{MAX_CLIMB_RATE} AND {MAX_CLIMB_RATE}) """ diff --git a/migrations/versions/5413cb96c44d_statistics_refactoring.py b/migrations/versions/5413cb96c44d_statistics_refactoring.py new file mode 100644 index 0000000..ea06577 --- /dev/null +++ b/migrations/versions/5413cb96c44d_statistics_refactoring.py @@ -0,0 +1,131 @@ +"""Statistics Refactoring + +Revision ID: 5413cb96c44d +Revises: 2ab0bbb8b49d +Create Date: 2020-12-13 13:13:26.242853 + +""" +from alembic import op +import sqlalchemy as sa + + +# revision identifiers, used by Alembic. +revision = '5413cb96c44d' +down_revision = '2ab0bbb8b49d' +branch_labels = None +depends_on = None + + +def upgrade(): + # ### commands auto generated by Alembic - please adjust! ### + op.add_column('coverage_statistics', sa.Column('max_signal_quality', sa.Float(precision=2), nullable=True)) + op.add_column('coverage_statistics', sa.Column('min_altitude', sa.Float(precision=2), nullable=True)) + op.add_column('coverage_statistics', sa.Column('max_altitude', sa.Float(precision=2), nullable=True)) + + op.create_table('sender_coverage_statistics', + sa.Column('id', sa.Integer(), nullable=False), + sa.Column('date', sa.Date(), nullable=True), + sa.Column('location_mgrs_short', sa.String(length=9), nullable=True), + sa.Column('is_trustworthy', sa.Boolean(), nullable=True), + sa.Column('messages_count', sa.Integer(), nullable=True), + sa.Column('max_distance', sa.Float(precision=2), nullable=True), + sa.Column('max_normalized_quality', sa.Float(precision=2), nullable=True), + sa.Column('max_signal_quality', sa.Float(precision=2), nullable=True), + sa.Column('min_altitude', sa.Float(precision=2), nullable=True), + sa.Column('max_altitude', sa.Float(precision=2), nullable=True), + sa.Column('receivers_count', sa.Integer(), nullable=True), + sa.Column('sender_id', sa.Integer(), nullable=True), + sa.ForeignKeyConstraint(['sender_id'], ['senders.id'], ondelete='CASCADE'), + sa.PrimaryKeyConstraint('id') + ) + op.create_index('idx_sender_coverage_statistics_uc', 'sender_coverage_statistics', ['date', 'sender_id', 'location_mgrs_short', 'is_trustworthy'], unique=True) + op.create_index(op.f('ix_sender_coverage_statistics_sender_id'), 'sender_coverage_statistics', ['sender_id'], unique=False) + + op.create_table('receiver_coverage_statistics', + sa.Column('id', sa.Integer(), nullable=False), + sa.Column('date', sa.Date(), nullable=True), + sa.Column('location_mgrs_short', sa.String(length=9), nullable=True), + sa.Column('is_trustworthy', sa.Boolean(), nullable=True), + sa.Column('messages_count', sa.Integer(), nullable=True), + sa.Column('max_distance', sa.Float(precision=2), nullable=True), + sa.Column('max_normalized_quality', sa.Float(precision=2), nullable=True), + sa.Column('max_signal_quality', sa.Float(precision=2), nullable=True), + sa.Column('min_altitude', sa.Float(precision=2), nullable=True), + sa.Column('max_altitude', sa.Float(precision=2), nullable=True), + sa.Column('senders_count', sa.Integer(), nullable=True), + sa.Column('receiver_id', sa.Integer(), nullable=True), + sa.ForeignKeyConstraint(['receiver_id'], ['receivers.id'], ondelete='CASCADE'), + sa.PrimaryKeyConstraint('id') + ) + op.create_index('idx_receiver_coverage_statistics_uc', 'receiver_coverage_statistics', ['date', 'receiver_id', 'location_mgrs_short', 'is_trustworthy'], unique=True) + op.create_index(op.f('ix_receiver_coverage_statistics_receiver_id'), 'receiver_coverage_statistics', ['receiver_id'], unique=False) + + op.create_table('aggregate_coverage_statistics', + sa.Column('id', sa.Integer(), nullable=False), + sa.Column('date', sa.Date(), nullable=True), + sa.Column('location_mgrs_short', sa.String(length=9), nullable=True), + sa.Column('is_trustworthy', sa.Boolean(), nullable=True), + sa.Column('messages_count', sa.Integer(), nullable=True), + sa.Column('max_distance', sa.Float(precision=2), nullable=True), + sa.Column('max_normalized_quality', sa.Float(precision=2), nullable=True), + sa.Column('max_signal_quality', sa.Float(precision=2), nullable=True), + sa.Column('min_altitude', sa.Float(precision=2), nullable=True), + sa.Column('max_altitude', sa.Float(precision=2), nullable=True), + sa.Column('senders_count', sa.Integer(), nullable=True), + sa.Column('receivers_count', sa.Integer(), nullable=True), + sa.PrimaryKeyConstraint('id') + ) + op.create_index('idx_aggregate_coverage_statistics_uc', 'aggregate_coverage_statistics', ['date', 'location_mgrs_short', 'is_trustworthy'], unique=True) + + op.drop_index('idx_relation_statistics_date_sender_id', table_name='relation_statistics') + op.drop_index('idx_relation_statistics_uc', table_name='relation_statistics') + op.drop_index('ix_relation_statistics_receiver_id', table_name='relation_statistics') + op.drop_index('ix_relation_statistics_sender_id', table_name='relation_statistics') + op.drop_table('relation_statistics') + + op.rename_table('sender_direction_statistics', 'direction_statistics') + op.drop_index('idx_sender_direction_statistics_uc') + op.create_index('idx_direction_statistics_uc', 'direction_statistics', ['sender_id', 'receiver_id'], unique=True) + # ### end Alembic commands ### + + +def downgrade(): + # ### commands auto generated by Alembic - please adjust! ### + op.rename_table('direction_statistics', 'sender_direction_statistics') + op.drop_index('idx_direction_statistics_uc') + op.create_index('idx_sender_direction_statistics_uc', 'sender_direction_statistics', ['sender_id', 'receiver_id'], unique=True) + + op.create_table('relation_statistics', + sa.Column('id', sa.INTEGER(), autoincrement=True, nullable=False), + sa.Column('date', sa.DATE(), autoincrement=False, nullable=True), + sa.Column('is_trustworthy', sa.BOOLEAN(), autoincrement=False, nullable=True), + sa.Column('messages_count', sa.INTEGER(), autoincrement=False, nullable=True), + sa.Column('max_distance', sa.REAL(), autoincrement=False, nullable=True), + sa.Column('max_normalized_quality', sa.REAL(), autoincrement=False, nullable=True), + sa.Column('sender_id', sa.INTEGER(), autoincrement=False, nullable=True), + sa.Column('receiver_id', sa.INTEGER(), autoincrement=False, nullable=True), + sa.Column('coverages_count', sa.INTEGER(), autoincrement=False, nullable=True), + sa.ForeignKeyConstraint(['receiver_id'], ['receivers.id'], name='relation_statistics_receiver_id_fkey', ondelete='CASCADE'), + sa.ForeignKeyConstraint(['sender_id'], ['senders.id'], name='relation_statistics_sender_id_fkey', ondelete='CASCADE'), + sa.PrimaryKeyConstraint('id', name='relation_statistics_pkey') + ) + op.create_index('ix_relation_statistics_sender_id', 'relation_statistics', ['sender_id'], unique=False) + op.create_index('ix_relation_statistics_receiver_id', 'relation_statistics', ['receiver_id'], unique=False) + op.create_index('idx_relation_statistics_uc', 'relation_statistics', ['date', 'sender_id', 'receiver_id', 'is_trustworthy'], unique=True) + op.create_index('idx_relation_statistics_date_sender_id', 'relation_statistics', ['date', 'sender_id'], unique=False) + + op.drop_index('idx_aggregate_coverage_statistics_uc', table_name='aggregate_coverage_statistics') + op.drop_table('aggregate_coverage_statistics') + + op.drop_index(op.f('ix_receiver_coverage_statistics_receiver_id'), table_name='receiver_coverage_statistics') + op.drop_index('idx_receiver_coverage_statistics_uc', table_name='receiver_coverage_statistics') + op.drop_table('receiver_coverage_statistics') + + op.drop_index(op.f('ix_sender_coverage_statistics_sender_id'), table_name='sender_coverage_statistics') + op.drop_index('idx_sender_coverage_statistics_uc', table_name='sender_coverage_statistics') + op.drop_table('sender_coverage_statistics') + + op.drop_column('coverage_statistics', 'max_altitude') + op.drop_column('coverage_statistics', 'min_altitude') + op.drop_column('coverage_statistics', 'max_signal_quality') + # ### end Alembic commands ###