kopia lustrzana https://github.com/glidernet/ogn-python
Added ReceiverStatusStatistic
rodzic
d990352f5b
commit
f29e2a49be
|
@ -190,25 +190,6 @@ def sender_position_csv_strings_to_db(lines):
|
|||
WHERE ST_Intersects(tmp.location, e.rast);
|
||||
""")
|
||||
|
||||
# Update sender position statistics
|
||||
cursor.execute(f"""
|
||||
INSERT INTO sender_position_statistics AS sps (date, dstcall, address_type, aircraft_type, stealth, software_version, hardware_version, messages_count)
|
||||
SELECT
|
||||
tmp.reference_timestamp::DATE AS date,
|
||||
tmp.dstcall,
|
||||
tmp.address_type,
|
||||
tmp.aircraft_type,
|
||||
tmp.stealth,
|
||||
tmp.software_version,
|
||||
tmp.hardware_version,
|
||||
COUNT(tmp.*) AS messages_count
|
||||
FROM {tmp_tablename} AS tmp
|
||||
GROUP BY date, dstcall, address_type, aircraft_type, stealth, software_version, hardware_version
|
||||
ON CONFLICT (date, dstcall, address_type, aircraft_type, stealth, software_version, hardware_version) DO UPDATE
|
||||
SET
|
||||
messages_count = EXCLUDED.messages_count + sps.messages_count;
|
||||
""")
|
||||
|
||||
# Update senders
|
||||
cursor.execute(f"""
|
||||
INSERT INTO senders AS s (firstseen, lastseen, name, aircraft_type, stealth, address, software_version, hardware_version, real_address)
|
||||
|
@ -247,6 +228,25 @@ def sender_position_csv_strings_to_db(lines):
|
|||
|
||||
SQL_TRUSTWORTHY = get_sql_trustworthy(source_table_alias='tmp')
|
||||
|
||||
# Update sender position statistics
|
||||
cursor.execute(f"""
|
||||
INSERT INTO sender_position_statistics AS sps (date, dstcall, address_type, aircraft_type, stealth, software_version, hardware_version, messages_count)
|
||||
SELECT
|
||||
tmp.reference_timestamp::DATE AS date,
|
||||
tmp.dstcall,
|
||||
tmp.address_type,
|
||||
tmp.aircraft_type,
|
||||
tmp.stealth,
|
||||
tmp.software_version,
|
||||
tmp.hardware_version,
|
||||
COUNT(tmp.*) AS messages_count
|
||||
FROM {tmp_tablename} AS tmp
|
||||
GROUP BY date, dstcall, address_type, aircraft_type, stealth, software_version, hardware_version
|
||||
ON CONFLICT (date, dstcall, address_type, aircraft_type, stealth, software_version, hardware_version) DO UPDATE
|
||||
SET
|
||||
messages_count = EXCLUDED.messages_count + sps.messages_count;
|
||||
""")
|
||||
|
||||
# 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)
|
||||
|
@ -425,6 +425,22 @@ def receiver_status_csv_strings_to_db(lines):
|
|||
rec_input_noise = EXCLUDED.rec_input_noise;
|
||||
""")
|
||||
|
||||
# Update receiver position statistics
|
||||
cursor.execute(f"""
|
||||
INSERT INTO receiver_status_statistics AS rss (date, receiver_id, version, platform, messages_count)
|
||||
SELECT
|
||||
tmp.reference_timestamp::DATE AS date,
|
||||
r.id AS receiver_id,
|
||||
COALESCE(tmp.version, ''),
|
||||
COALESCE(tmp.platform, ''),
|
||||
COUNT(tmp.*) AS messages_count
|
||||
FROM {tmp_tablename} AS tmp INNER JOIN receivers AS r ON tmp.name = r.name
|
||||
GROUP BY tmp.reference_timestamp::DATE, r.id, tmp.version, tmp.platform
|
||||
ON CONFLICT (date, receiver_id, version, platform) DO UPDATE
|
||||
SET
|
||||
messages_count = EXCLUDED.messages_count + rss.messages_count;
|
||||
""")
|
||||
|
||||
# Insert all the beacons
|
||||
all_fields = ', '.join(RECEIVER_STATUS_BEACON_FIELDS)
|
||||
cursor.execute(f"""
|
||||
|
|
|
@ -23,3 +23,4 @@ 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
|
||||
|
|
|
@ -0,0 +1,20 @@
|
|||
from app import db
|
||||
|
||||
|
||||
class ReceiverStatusStatistic(db.Model):
|
||||
__tablename__ = "receiver_status_statistics"
|
||||
|
||||
id = db.Column(db.Integer, primary_key=True)
|
||||
|
||||
date = db.Column(db.Date, nullable=False)
|
||||
|
||||
version = db.Column(db.String, nullable=False)
|
||||
platform = db.Column(db.String, nullable=False)
|
||||
|
||||
messages_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("status_statistics", order_by=date.desc()))
|
||||
|
||||
__table_args__ = (db.Index('idx_receiver_status_statistics_uc', 'date', 'receiver_id', 'version', 'platform', unique=True), )
|
|
@ -0,0 +1,41 @@
|
|||
"""Added ReceiverStatusStatistic
|
||||
|
||||
Revision ID: 0dff4f629978
|
||||
Revises: 7f5b8f65a977
|
||||
Create Date: 2020-12-04 18:36:12.884785
|
||||
|
||||
"""
|
||||
from alembic import op
|
||||
import sqlalchemy as sa
|
||||
|
||||
|
||||
# revision identifiers, used by Alembic.
|
||||
revision = '0dff4f629978'
|
||||
down_revision = '7f5b8f65a977'
|
||||
branch_labels = None
|
||||
depends_on = None
|
||||
|
||||
|
||||
def upgrade():
|
||||
# ### commands auto generated by Alembic - please adjust! ###
|
||||
op.create_table('receiver_status_statistics',
|
||||
sa.Column('id', sa.Integer(), nullable=False),
|
||||
sa.Column('date', sa.Date(), nullable=False),
|
||||
sa.Column('version', sa.String(), nullable=False),
|
||||
sa.Column('platform', sa.String(), nullable=False),
|
||||
sa.Column('messages_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_status_statistics_uc', 'receiver_status_statistics', ['date', 'receiver_id', 'version', 'platform'], unique=True)
|
||||
op.create_index(op.f('ix_receiver_status_statistics_receiver_id'), 'receiver_status_statistics', ['receiver_id'], unique=False)
|
||||
# ### end Alembic commands ###
|
||||
|
||||
|
||||
def downgrade():
|
||||
# ### commands auto generated by Alembic - please adjust! ###
|
||||
op.drop_index(op.f('ix_receiver_status_statistics_receiver_id'), table_name='receiver_status_statistics')
|
||||
op.drop_index('idx_receiver_status_statistics_uc', table_name='receiver_status_statistics')
|
||||
op.drop_table('receiver_status_statistics')
|
||||
# ### end Alembic commands ###
|
Ładowanie…
Reference in New Issue