Replace ranks with pareto values (#161)

pull/78/head
Meisterschueler 2020-12-08 19:28:18 +01:00 zatwierdzone przez GitHub
rodzic 4e223b9941
commit b4c7078fdb
Nie znaleziono w bazie danych klucza dla tego podpisu
ID klucza GPG: 4AEE18F83AFDEB23
5 zmienionych plików z 139 dodań i 84 usunięć

Wyświetl plik

@ -1,6 +1,6 @@
import os
import re
from datetime import date, time, datetime
from datetime import date, time, datetime, timedelta
from flask import request, render_template, send_file, abort, current_app, make_response
from sqlalchemy.orm.exc import NoResultFound
@ -226,25 +226,78 @@ def sender_ranking():
@cache.cached(query_string=True)
def receiver_ranking():
sel_country = request.args.get("country")
DAYS_FOR_AVERAGING = 28
countries = db.session.query(Country) \
.filter(Country.gid == ReceiverRanking.country_id) \
.filter(ReceiverRanking.date == date.today()) \
.order_by(Country.iso2)
# Make the rank for today
rank_today = db.session.query(
ReceiverRanking.receiver_id,
ReceiverRanking.country_id,
db.func.rank().over(partition_by=ReceiverRanking.country_id, order_by=ReceiverRanking.local_distance_pareto.desc()).label('local_rank'),
db.func.rank().over(order_by=ReceiverRanking.global_distance_pareto.desc()).label('global_rank')) \
.filter(ReceiverRanking.date == date.today()) \
.subquery()
# Sum the pareto values for the last 28 days
longtime_today = db.session.query(
ReceiverRanking.receiver_id,
ReceiverRanking.country_id,
db.func.sum(ReceiverRanking.local_distance_pareto).label('local_distance_pareto'),
db.func.sum(ReceiverRanking.global_distance_pareto).label('global_distance_pareto')) \
.filter(ReceiverRanking.date.between(date.today() - timedelta(days=DAYS_FOR_AVERAGING), date.today())) \
.group_by(ReceiverRanking.receiver_id, ReceiverRanking.country_id) \
.subquery()
# ... and make the longtime_ranking for today
longtime_rank_today = db.session.query(
longtime_today.c.receiver_id,
longtime_today.c.country_id,
db.func.rank().over(partition_by=longtime_today.c.country_id, order_by=longtime_today.c.local_distance_pareto.desc()).label('local_rank'),
db.func.rank().over(order_by=longtime_today.c.global_distance_pareto.desc()).label('global_rank')) \
.subquery()
# Sum the pareto values for the last 28 days (beginning from yesterday!)
longtime_yesterday = db.session.query(
ReceiverRanking.receiver_id,
ReceiverRanking.country_id,
db.func.sum(ReceiverRanking.local_distance_pareto).label('local_distance_pareto'),
db.func.sum(ReceiverRanking.global_distance_pareto).label('global_distance_pareto')) \
.filter(ReceiverRanking.date.between(date.today() - timedelta(days=DAYS_FOR_AVERAGING + 1), date.today() - timedelta(days=1))) \
.group_by(ReceiverRanking.receiver_id, ReceiverRanking.country_id) \
.subquery()
# ... and make the longtime_ranking for yesterday
longtime_rank_yesterday = db.session.query(
longtime_yesterday.c.receiver_id,
longtime_yesterday.c.country_id,
db.func.rank().over(partition_by=longtime_yesterday.c.country_id, order_by=longtime_yesterday.c.local_distance_pareto.desc()).label('local_rank'),
db.func.rank().over(order_by=longtime_yesterday.c.global_distance_pareto.desc()).label('global_rank')) \
.subquery()
# we need the ReceiverRanking, but only from today
receiver_rankings_from_today = db.session.query(ReceiverRanking).filter(ReceiverRanking.date == date.today()).subquery()
receiver_rankings_from_today = db.aliased(ReceiverRanking, receiver_rankings_from_today)
# Get receiver selection list
if sel_country:
ranking = db.session.query(ReceiverRanking) \
.join(Country) \
.filter(db.and_(ReceiverRanking.country_id == Country.gid, Country.iso2 == sel_country)) \
.filter(db.and_(ReceiverRanking.date == date.today())) \
.order_by(ReceiverRanking.global_rank.asc()) \
.all()
ranking = db.session.query(Receiver, receiver_rankings_from_today, rank_today.c.local_rank.label('rank_today'), longtime_rank_today.c.local_rank.label('longtime_rank_today'), longtime_rank_yesterday.c.local_rank.label('longtime_rank_yesterday')) \
.join(receiver_rankings_from_today, isouter=True) \
.join(rank_today, rank_today.c.receiver_id == Receiver.id, isouter=True) \
.join(longtime_rank_yesterday, longtime_rank_yesterday.c.receiver_id == Receiver.id, isouter=True) \
.join(longtime_rank_today, longtime_rank_today.c.receiver_id == Receiver.id) \
.filter(db.and_(Receiver.country_id == Country.gid, Country.iso2 == sel_country)) \
.order_by(longtime_rank_today.c.local_rank)
else:
ranking = db.session.query(ReceiverRanking) \
.filter(db.and_(ReceiverRanking.date == date.today())) \
.order_by(ReceiverRanking.global_rank.asc()) \
.all()
ranking = db.session.query(Receiver, receiver_rankings_from_today, rank_today.c.global_rank.label('rank_today'), longtime_rank_today.c.global_rank.label('longtime_rank_today'), longtime_rank_yesterday.c.global_rank.label('longtime_rank_yesterday')) \
.join(receiver_rankings_from_today, isouter=True) \
.join(rank_today, rank_today.c.receiver_id == Receiver.id, isouter=True) \
.join(longtime_rank_yesterday, longtime_rank_yesterday.c.receiver_id == Receiver.id, isouter=True) \
.join(longtime_rank_today, longtime_rank_today.c.receiver_id == Receiver.id) \
.order_by(longtime_rank_today.c.global_rank)
return render_template(
"receiver_ranking.html",

Wyświetl plik

@ -7,12 +7,8 @@ class ReceiverRanking(db.Model):
id = db.Column(db.Integer, primary_key=True)
date = db.Column(db.Date)
local_rank = db.Column(db.Integer)
global_rank = db.Column(db.Integer)
longtime_local_rank = db.Column(db.Integer)
longtime_local_rank_delta = db.Column(db.Integer)
longtime_global_rank = db.Column(db.Integer)
longtime_global_rank_delta = db.Column(db.Integer)
local_distance_pareto = db.Column(db.Integer)
global_distance_pareto = db.Column(db.Integer)
max_distance = db.Column(db.Float(precision=2))
max_normalized_quality = db.Column(db.Float(precision=2))

Wyświetl plik

@ -81,14 +81,14 @@ def update_statistics(date_str=None):
DELETE FROM receiver_rankings
WHERE date = '{date_str}';
INSERT INTO receiver_rankings AS rr (date, receiver_id, country_id, local_rank, global_rank, max_distance, max_normalized_quality, messages_count, coverages_count, senders_count)
INSERT INTO receiver_rankings AS rr (date, receiver_id, country_id, local_distance_pareto, global_distance_pareto, max_distance, max_normalized_quality, messages_count, coverages_count, senders_count)
SELECT
rs.date,
rs.receiver_id,
r.country_id,
RANK() OVER (PARTITION BY rs.date, r.country_id ORDER BY rs.max_distance DESC) AS local_rank,
RANK() OVER (ORDER BY rs.max_distance DESC) AS global_rank,
1.0 * RANK() OVER (PARTITION BY rs.date, r.country_id ORDER BY rs.max_distance) / COUNT(rs.*) OVER (PARTITION BY rs.date, r.country_id) AS local_distance_pareto,
1.0 * RANK() OVER (PARTITION BY rs.date ORDER BY rs.max_distance) / COUNT(rs.*) OVER (PARTITION BY rs.date) AS global_distance_pareto,
rs.max_distance,
rs.max_normalized_quality,
@ -100,54 +100,6 @@ def update_statistics(date_str=None):
WHERE rs.date = '{date_str}' AND rs.is_trustworthy IS TRUE;
""")
db.session.execute(f"""
UPDATE receiver_rankings AS rr
SET
longtime_global_rank = sq3.longtime_global_rank,
longtime_local_rank = sq3.longtime_local_rank
FROM (
SELECT
sq2.receiver_id,
RANK() OVER (ORDER BY sq2.longtime_global_scores DESC) AS longtime_global_rank,
RANK() OVER (PARTITION BY sq2.country_id ORDER BY sq2.longtime_local_scores DESC) AS longtime_local_rank
FROM (
SELECT
sq.receiver_id,
sq.country_id,
SUM(sq.global_scores) AS longtime_global_scores,
SUM(sq.local_scores) AS longtime_local_scores
FROM (
SELECT
rr.receiver_id,
rr.country_id,
rr.date,
MAX(rr.global_rank) OVER (PARTITION BY rr.date) + 1 - rr.global_rank AS global_scores,
MAX(rr.local_rank) OVER (PARTITION BY rr.country_id, rr.date) + 1 - rr.local_rank AS local_scores
FROM receiver_rankings AS rr
) AS sq
WHERE sq.date BETWEEN DATE '{date_str}' - INTEGER '28' AND DATE '{date_str}'
GROUP BY sq.receiver_id, sq.country_id
) AS sq2
) AS sq3
WHERE rr.receiver_id = sq3.receiver_id AND rr.date = '{date_str}';
""")
db.session.execute(f"""
UPDATE receiver_rankings AS rr
SET
longtime_global_rank_delta = sq.longtime_global_rank_yesterday - rr.longtime_global_rank,
longtime_local_rank_delta = sq.longtime_local_rank_yesterday - rr.longtime_local_rank
FROM (
SELECT
rr.receiver_id,
rr.longtime_global_rank AS longtime_global_rank_yesterday,
rr.longtime_local_rank AS longtime_local_rank_yesterday
FROM receiver_rankings AS rr
WHERE rr.date = DATE '{date_str}' - INTEGER '1'
) AS sq
WHERE rr.receiver_id = sq.receiver_id;
""")
db.session.commit()

Wyświetl plik

@ -36,23 +36,18 @@
</thead>
<tbody>
{% for entry in ranking %}
{% if sel_country is none or sel_country == '' %}
{% set rank = entry.global_rank %}{% set longtime_rank = entry.longtime_global_rank %}{% set longtime_rank_delta = entry.longtime_global_rank_delta %}
{% else %}
{% set rank = entry.local_rank %}{% set longtime_rank = entry.longtime_local_rank %}{% set longtime_rank_delta = entry.longtime_local_rank_delta %}
{% endif %}
{% for (receiver, ranking, current, today, yesterday) in ranking %}
<tr>
<td class="text-right">{{ longtime_rank }}</td>
<td class="text-right">{% if longtime_rank_delta is none %}{% elif longtime_rank_delta > 0 %}<span class="text-success"><i class="fa fa-long-arrow-up"></i>{{ longtime_rank_delta }}</span>{% elif longtime_rank_delta < 0 %}<span class="text-danger"><i class="fa fa-long-arrow-down"></i>{{ -longtime_rank_delta }}</span>{% endif %}</td>
<td class="text-right">{{ rank }}</td>
<td>{{ entry.receiver.country|to_html_flag|safe }} {{ entry.receiver|to_html_link|safe }}</td>
<td>{{ entry.receiver.airport|to_html_link|safe }}</td>
<td class="text-right">{{ '%0.1f' | format(entry.max_distance/1000.0) }}</td>
<td class="text-right">{{ '%0.1f' | format(entry.max_normalized_quality) }}</td>
<td class="text-right">{{ entry.senders_count }}</td>
<td class="text-right">{{ entry.coverages_count }}</td>
<td class="text-right">{{ entry.messages_count }}</td>
<td class="text-right">{{ today }}</td>
<td class="text-right">{% if yesterday is none %}(new){% elif yesterday - today > 0 %}<span class="text-success"><i class="fa fa-long-arrow-up"></i>{{ yesterday - today }}</span>{% elif yesterday - today < 0 %}<span class="text-danger"><i class="fa fa-long-arrow-down"></i>{{ today - yesterday }}</span>{% endif %}</td>
<td class="text-right">{% if current is not none %}{{ current }}{% else %}-{% endif %}</td>
<td>{{ receiver.country|to_html_flag|safe }} {{ receiver|to_html_link|safe }}</td>
<td>{{ receiver.airport|to_html_link|safe }}</td>
<td class="text-right">{% if ranking is not none %}{{ '%0.1f' | format(ranking.max_distance/1000.0) }}{% else %}-{% endif %}</td>
<td class="text-right">{% if ranking is not none %}{{ '%0.1f' | format(ranking.max_normalized_quality) }}{% else %}-{% endif %}</td>
<td class="text-right">{% if ranking is not none %}{{ ranking.senders_count }}{% else %}-{% endif %}</td>
<td class="text-right">{% if ranking is not none %}{{ ranking.coverages_count }}{% else %}-{% endif %}</td>
<td class="text-right">{% if ranking is not none %}{{ ranking.messages_count }}{% else %}-{% endif %}</td>
</tr>
{% endfor %}
</tbody>

Wyświetl plik

@ -0,0 +1,59 @@
"""Replaced 'rank' with 'pareto'
Revision ID: f3afd6197391
Revises: 310027ddeea9
Create Date: 2020-12-08 08:41:49.170716
"""
from alembic import op
import sqlalchemy as sa
# revision identifiers, used by Alembic.
revision = 'f3afd6197391'
down_revision = '310027ddeea9'
branch_labels = None
depends_on = None
def upgrade():
# ### commands auto generated by Alembic - please adjust! ###
op.add_column('receiver_rankings', sa.Column('global_distance_pareto', sa.Float(precision=2), nullable=True))
op.add_column('receiver_rankings', sa.Column('local_distance_pareto', sa.Float(precision=2), nullable=True))
op.drop_column('receiver_rankings', 'global_rank')
op.drop_column('receiver_rankings', 'longtime_local_rank_delta')
op.drop_column('receiver_rankings', 'longtime_global_rank_delta')
op.drop_column('receiver_rankings', 'longtime_global_rank')
op.drop_column('receiver_rankings', 'longtime_local_rank')
op.drop_column('receiver_rankings', 'local_rank')
# ### end Alembic commands ###
op.execute("""
UPDATE receiver_rankings AS rr
SET
local_distance_pareto = sq.local_distance_pareto,
global_distance_pareto = sq.global_distance_pareto
FROM
(
SELECT
date,
receiver_id,
1.0 * RANK() OVER (PARTITION BY date, country_id ORDER BY max_distance) / COUNT(*) OVER (PARTITION BY date, country_id) AS local_distance_pareto,
1.0 * RANK() OVER (PARTITION BY date ORDER BY max_distance) / COUNT(*) OVER (PARTITION BY date) AS global_distance_pareto
FROM receiver_rankings
) AS sq
WHERE rr.date = sq.date AND rr.receiver_id = sq.receiver_id;
""")
def downgrade():
# ### commands auto generated by Alembic - please adjust! ###
op.add_column('receiver_rankings', sa.Column('local_rank', sa.Float(precision=2), autoincrement=False, nullable=True))
op.add_column('receiver_rankings', sa.Column('longtime_local_rank', sa.Float(precision=2), autoincrement=False, nullable=True))
op.add_column('receiver_rankings', sa.Column('longtime_global_rank', sa.Float(precision=2), autoincrement=False, nullable=True))
op.add_column('receiver_rankings', sa.Column('longtime_global_rank_delta', sa.Float(precision=2), autoincrement=False, nullable=True))
op.add_column('receiver_rankings', sa.Column('longtime_local_rank_delta', sa.Float(precision=2), autoincrement=False, nullable=True))
op.add_column('receiver_rankings', sa.Column('global_rank', sa.Float(precision=2), autoincrement=False, nullable=True))
op.drop_column('receiver_rankings', 'local_distance_pareto')
op.drop_column('receiver_rankings', 'global_distance_pareto')
# ### end Alembic commands ###