mirror of
https://github.com/Tautulli/Tautulli.git
synced 2025-07-10 15:32:38 -07:00
Rewrite get_history query for grouping
This commit is contained in:
parent
8791babf8e
commit
179eaf1bbe
2 changed files with 123 additions and 65 deletions
|
@ -26,56 +26,104 @@ class DataFactory(object):
|
||||||
def __init__(self):
|
def __init__(self):
|
||||||
pass
|
pass
|
||||||
|
|
||||||
def get_history(self, kwargs=None, custom_where=None):
|
def get_history(self, kwargs=None, custom_where=None, grouping=0):
|
||||||
data_tables = datatables.DataTables()
|
data_tables = datatables.DataTables()
|
||||||
|
|
||||||
|
group_by = 'group_start_id' if grouping else 'id'
|
||||||
|
|
||||||
|
from_table = '(SELECT ' \
|
||||||
|
' /* Session info */ ' \
|
||||||
|
' (CASE ' \
|
||||||
|
' /* IF rating_key AND user are NOT EQUAL to previous row */ ' \
|
||||||
|
' WHEN t1.rating_key <> ( ' \
|
||||||
|
' SELECT rating_key FROM session_history WHERE id = ( ' \
|
||||||
|
' SELECT MAX(id) FROM session_history WHERE id < t1.id)) ' \
|
||||||
|
' AND t1.user <> ( ' \
|
||||||
|
' SELECT user FROM session_history WHERE id = ( ' \
|
||||||
|
' SELECT MAX(id) FROM session_history WHERE id < t1.id)) ' \
|
||||||
|
' /* THEN select the row */ ' \
|
||||||
|
' THEN t1.id ' \
|
||||||
|
' /* IF rating_key OR user are NOT EQUAL to previous row */ ' \
|
||||||
|
' WHEN ( ' \
|
||||||
|
' SELECT MIN(id) FROM session_history WHERE id > ( ' \
|
||||||
|
' SELECT MAX(id) FROM session_history ' \
|
||||||
|
' WHERE (rating_key <> t1.rating_key OR user <> t1.user) AND id < t1.id)) IS NULL /* First row */ ' \
|
||||||
|
' /* THEN select the first row */ ' \
|
||||||
|
' THEN (SELECT MIN(id) FROM session_history) ' \
|
||||||
|
' /* ELSE select the row where the rating key or user changed */ ' \
|
||||||
|
' ELSE (SELECT MIN(id) FROM session_history ' \
|
||||||
|
' WHERE id > (SELECT MAX(id) FROM session_history ' \
|
||||||
|
' WHERE (rating_key <> t1.rating_key OR user <> t1.user) AND id < t1.id)) ' \
|
||||||
|
' END) AS group_start_id, ' \
|
||||||
|
' t1.id, ' \
|
||||||
|
' t1.started as date, ' \
|
||||||
|
' t1.started, ' \
|
||||||
|
' t1.stopped, ' \
|
||||||
|
' (CASE WHEN t1.stopped > 0 THEN (t1.stopped - t1.started) ELSE 0 END) AS duration, ' \
|
||||||
|
' (CASE WHEN t1.paused_counter IS NULL THEN 0 ELSE t1.paused_counter END) AS paused_counter, ' \
|
||||||
|
' /* User and player info */ ' \
|
||||||
|
' t1.user_id, ' \
|
||||||
|
' t1.user, ' \
|
||||||
|
' (CASE WHEN t2.friendly_name IS NULL THEN t1.user ELSE t2.friendly_name END) as friendly_name, ' \
|
||||||
|
' t1.player, ' \
|
||||||
|
' t1.ip_address, ' \
|
||||||
|
' /* Metadata info */ ' \
|
||||||
|
' t3.media_type, ' \
|
||||||
|
' t3.rating_key, ' \
|
||||||
|
' t3.parent_rating_key, ' \
|
||||||
|
' t3.grandparent_rating_key, ' \
|
||||||
|
' t3.full_title, ' \
|
||||||
|
' t3.parent_title, ' \
|
||||||
|
' t3.year, ' \
|
||||||
|
' t3.media_index, ' \
|
||||||
|
' t3.parent_media_index, ' \
|
||||||
|
' t3.thumb, ' \
|
||||||
|
' t3.parent_thumb, ' \
|
||||||
|
' t3.grandparent_thumb, ' \
|
||||||
|
' /* Stream info */ ' \
|
||||||
|
' ((CASE WHEN t1.view_offset IS NULL THEN 0.1 ELSE t1.view_offset * 1.0 END) / ' \
|
||||||
|
' (CASE WHEN t3.duration IS NULL THEN 1.0 ELSE t3.duration * 1.0 END) * 100) as percent_complete, ' \
|
||||||
|
' t4.video_decision ' \
|
||||||
|
'FROM session_history AS t1 ' \
|
||||||
|
' LEFT OUTER JOIN users AS t2 ON t1.user_id = t2.user_id ' \
|
||||||
|
' JOIN session_history_metadata AS t3 ON t1.id = t3.id ' \
|
||||||
|
' JOIN session_history_media_info AS t4 ON t1.id = t4.id) '
|
||||||
|
|
||||||
columns = ['session_history.id',
|
columns = ['group_start_id',
|
||||||
'session_history.started as date',
|
'id',
|
||||||
'(CASE WHEN users.friendly_name IS NULL THEN session_history'
|
'date',
|
||||||
'.user ELSE users.friendly_name END) as friendly_name',
|
'MIN(started) AS started',
|
||||||
'session_history.player',
|
'MAX(stopped) AS stopped',
|
||||||
'session_history.ip_address',
|
'SUM(duration) - SUM(paused_counter) AS duration',
|
||||||
'session_history_metadata.full_title as full_title',
|
'SUM(paused_counter) AS paused_counter',
|
||||||
'session_history_metadata.thumb',
|
'user_id',
|
||||||
'session_history_metadata.parent_thumb',
|
'user',
|
||||||
'session_history_metadata.grandparent_thumb',
|
'friendly_name',
|
||||||
'session_history_metadata.media_index',
|
'player',
|
||||||
'session_history_metadata.parent_media_index',
|
'ip_address',
|
||||||
'session_history_metadata.parent_title',
|
'media_type',
|
||||||
'session_history_metadata.year',
|
'rating_key',
|
||||||
'session_history.started',
|
'parent_rating_key',
|
||||||
'session_history.paused_counter',
|
'grandparent_rating_key',
|
||||||
'session_history.stopped',
|
'full_title',
|
||||||
'round((julianday(datetime(session_history.stopped, "unixepoch", "localtime")) - \
|
'parent_title',
|
||||||
julianday(datetime(session_history.started, "unixepoch", "localtime"))) * 86400) - \
|
'year',
|
||||||
(CASE WHEN session_history.paused_counter IS NULL THEN 0 \
|
'media_index',
|
||||||
ELSE session_history.paused_counter END) as duration',
|
'parent_media_index',
|
||||||
'((CASE WHEN session_history.view_offset IS NULL THEN 0.1 ELSE \
|
'thumb',
|
||||||
session_history.view_offset * 1.0 END) / \
|
'parent_thumb',
|
||||||
(CASE WHEN session_history_metadata.duration IS NULL THEN 1.0 ELSE \
|
'grandparent_thumb',
|
||||||
session_history_metadata.duration * 1.0 END) * 100) as percent_complete',
|
'percent_complete',
|
||||||
'session_history.grandparent_rating_key as grandparent_rating_key',
|
'video_decision',
|
||||||
'session_history.parent_rating_key as parent_rating_key',
|
'COUNT(*) AS group_count'
|
||||||
'session_history.rating_key as rating_key',
|
|
||||||
'session_history.user',
|
|
||||||
'session_history_metadata.media_type',
|
|
||||||
'session_history_media_info.video_decision',
|
|
||||||
'session_history.user_id as user_id'
|
|
||||||
]
|
]
|
||||||
try:
|
try:
|
||||||
query = data_tables.ssp_query(table_name='session_history',
|
query = data_tables.ssp_query(table_name=from_table,
|
||||||
columns=columns,
|
columns=columns,
|
||||||
custom_where=custom_where,
|
custom_where=custom_where,
|
||||||
group_by=[],
|
group_by=[group_by],
|
||||||
join_types=['LEFT OUTER JOIN',
|
join_types=[],
|
||||||
'JOIN',
|
join_tables=[],
|
||||||
'JOIN'],
|
|
||||||
join_tables=['users',
|
|
||||||
'session_history_metadata',
|
|
||||||
'session_history_media_info'],
|
|
||||||
join_evals=[['session_history.user_id', 'users.user_id'],
|
|
||||||
['session_history.id', 'session_history_metadata.id'],
|
|
||||||
['session_history.id', 'session_history_media_info.id']],
|
|
||||||
kwargs=kwargs)
|
kwargs=kwargs)
|
||||||
except:
|
except:
|
||||||
logger.warn("Unable to execute database query.")
|
logger.warn("Unable to execute database query.")
|
||||||
|
@ -86,7 +134,7 @@ class DataFactory(object):
|
||||||
'error': 'Unable to execute database query.'}
|
'error': 'Unable to execute database query.'}
|
||||||
|
|
||||||
history = query['result']
|
history = query['result']
|
||||||
|
|
||||||
rows = []
|
rows = []
|
||||||
for item in history:
|
for item in history:
|
||||||
if item["media_type"] == 'episode' and item["parent_thumb"]:
|
if item["media_type"] == 'episode' and item["parent_thumb"]:
|
||||||
|
@ -96,33 +144,35 @@ class DataFactory(object):
|
||||||
else:
|
else:
|
||||||
thumb = item["thumb"]
|
thumb = item["thumb"]
|
||||||
|
|
||||||
row = {"id": item['id'],
|
row = {"group_start_id": item["group_start_id"],
|
||||||
"date": item['date'],
|
"id": item["id"],
|
||||||
"friendly_name": item['friendly_name'],
|
"date": item["date"],
|
||||||
"player": item["player"],
|
|
||||||
"ip_address": item["ip_address"],
|
|
||||||
"full_title": item["full_title"],
|
|
||||||
"thumb": thumb,
|
|
||||||
"media_index": item["media_index"],
|
|
||||||
"parent_media_index": item["parent_media_index"],
|
|
||||||
"parent_title": item["parent_title"],
|
|
||||||
"year": item["year"],
|
|
||||||
"started": item["started"],
|
"started": item["started"],
|
||||||
"paused_counter": item["paused_counter"],
|
|
||||||
"stopped": item["stopped"],
|
"stopped": item["stopped"],
|
||||||
"duration": item["duration"],
|
"duration": item["duration"],
|
||||||
"percent_complete": item["percent_complete"],
|
"paused_counter": item["paused_counter"],
|
||||||
"grandparent_rating_key": item["grandparent_rating_key"],
|
"user_id": item["user_id"],
|
||||||
"parent_rating_key": item["parent_rating_key"],
|
|
||||||
"rating_key": item["rating_key"],
|
|
||||||
"user": item["user"],
|
"user": item["user"],
|
||||||
|
"friendly_name": item["friendly_name"],
|
||||||
|
"player": item["player"],
|
||||||
|
"ip_address": item["ip_address"],
|
||||||
"media_type": item["media_type"],
|
"media_type": item["media_type"],
|
||||||
|
"rating_key": item["rating_key"],
|
||||||
|
"parent_rating_key": item["parent_rating_key"],
|
||||||
|
"grandparent_rating_key": item["grandparent_rating_key"],
|
||||||
|
"full_title": item["full_title"],
|
||||||
|
"parent_title": item["parent_title"],
|
||||||
|
"year": item["year"],
|
||||||
|
"media_index": item["media_index"],
|
||||||
|
"parent_media_index": item["parent_media_index"],
|
||||||
|
"thumb": thumb,
|
||||||
"video_decision": item["video_decision"],
|
"video_decision": item["video_decision"],
|
||||||
"user_id": item["user_id"]
|
"percent_complete": item["percent_complete"],
|
||||||
|
"group_count": item["group_count"]
|
||||||
}
|
}
|
||||||
|
|
||||||
rows.append(row)
|
rows.append(row)
|
||||||
|
|
||||||
dict = {'recordsFiltered': query['filteredCount'],
|
dict = {'recordsFiltered': query['filteredCount'],
|
||||||
'recordsTotal': query['totalCount'],
|
'recordsTotal': query['totalCount'],
|
||||||
'data': rows,
|
'data': rows,
|
||||||
|
|
|
@ -569,7 +569,12 @@ class WebInterface(object):
|
||||||
message=message, timer=timer, quote=quote)
|
message=message, timer=timer, quote=quote)
|
||||||
|
|
||||||
@cherrypy.expose
|
@cherrypy.expose
|
||||||
def get_history(self, user=None, user_id=None, **kwargs):
|
def get_history(self, user=None, user_id=None, grouping=0, **kwargs):
|
||||||
|
|
||||||
|
if grouping == 'false':
|
||||||
|
grouping = 0
|
||||||
|
else:
|
||||||
|
grouping = plexpy.CONFIG.GROUP_HISTORY_TABLES
|
||||||
|
|
||||||
custom_where=[]
|
custom_where=[]
|
||||||
if user_id:
|
if user_id:
|
||||||
|
@ -588,9 +593,12 @@ class WebInterface(object):
|
||||||
if 'start_date' in kwargs:
|
if 'start_date' in kwargs:
|
||||||
start_date = kwargs.get('start_date', "")
|
start_date = kwargs.get('start_date', "")
|
||||||
custom_where = [['strftime("%Y-%m-%d", datetime(date, "unixepoch", "localtime"))', start_date]]
|
custom_where = [['strftime("%Y-%m-%d", datetime(date, "unixepoch", "localtime"))', start_date]]
|
||||||
|
if 'group_start_id' in kwargs:
|
||||||
|
group_start_id = kwargs.get('group_start_id', "")
|
||||||
|
custom_where = [['group_start_id', int(group_start_id)]]
|
||||||
|
|
||||||
data_factory = datafactory.DataFactory()
|
data_factory = datafactory.DataFactory()
|
||||||
history = data_factory.get_history(kwargs=kwargs, custom_where=custom_where)
|
history = data_factory.get_history(kwargs=kwargs, custom_where=custom_where, grouping=grouping)
|
||||||
|
|
||||||
cherrypy.response.headers['Content-type'] = 'application/json'
|
cherrypy.response.headers['Content-type'] = 'application/json'
|
||||||
return json.dumps(history)
|
return json.dumps(history)
|
||||||
|
|
Loading…
Add table
Add a link
Reference in a new issue