StatsDatabase.py 21 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418
  1. import os.path
  2. import random as rnd
  3. import typing
  4. import sqlite3
  5. import sys
  6. # TODO: double check this import
  7. # does it complain because libpcapreader is not a .py?
  8. import ID2TLib.libpcapreader as pr
  9. import Core.QueryParser as qp
  10. import pyparsing as pp
  11. def dict_gen(curs: sqlite3.Cursor):
  12. """
  13. Generates a dictionary of a sqlite3.Cursor object by fetching the query's results.
  14. Taken from Python Essential Reference by David Beazley.
  15. """
  16. field_names = [d[0] for d in curs.description]
  17. while True:
  18. rows = curs.fetchmany()
  19. if not rows:
  20. return
  21. for row in rows:
  22. yield dict(zip(field_names, row))
  23. class QueryExecutionException(Exception):
  24. pass
  25. class StatsDatabase:
  26. def __init__(self, db_path: str):
  27. """
  28. Creates a new StatsDatabase.
  29. :param db_path: The path to the database file
  30. """
  31. self.query_parser = qp.QueryParser()
  32. self.existing_db = os.path.exists(db_path)
  33. self.database = sqlite3.connect(db_path)
  34. self.cursor = self.database.cursor()
  35. # If DB not existing, create a new DB scheme
  36. if self.existing_db:
  37. if self.get_db_outdated():
  38. print('Statistics database outdated. Recreating database at: ', db_path)
  39. else:
  40. print('Located statistics database at: ', db_path)
  41. else:
  42. print('Statistics database not found. Creating new database at: ', db_path)
  43. def get_file_info(self):
  44. """
  45. Retrieves general file statistics from the database. This includes:
  46. - packetCount : Number of packets in the PCAP file
  47. - captureDuration : Duration of the packet capture in seconds
  48. - timestampFirstPacket : Timestamp of the first captured packet
  49. - timestampLastPacket : Timestamp of the last captured packet
  50. - avgPacketRate : Average packet rate
  51. - avgPacketSize : Average packet size
  52. - avgPacketsSentPerHost : Average number of packets sent per host
  53. - avgBandwidthIn : Average incoming bandwidth
  54. - avgBandwidthOut : Average outgoing bandwidth
  55. :return: a dictionary of keys (see above) and their respective values
  56. """
  57. return [r for r in dict_gen(
  58. self.cursor.execute('SELECT * FROM file_statistics'))][0]
  59. def get_db_exists(self):
  60. """
  61. :return: True if the database was already existent, otherwise False
  62. """
  63. return self.existing_db
  64. def get_db_outdated(self):
  65. """
  66. Retrieves the database version from the database and compares it to the version
  67. it should have to check whether the database is outdated and needs to be recreated.
  68. :return: True if the versions match, otherwise False
  69. """
  70. self.cursor.execute('PRAGMA user_version;')
  71. return self.cursor.fetchall()[0][0] != pr.pcap_processor.get_db_version()
  72. @staticmethod
  73. def _get_selector_keywords():
  74. """
  75. :return: a list of selector keywords
  76. """
  77. return ['most_used', 'least_used', 'avg', 'all']
  78. @staticmethod
  79. def _get_parametrized_selector_keywords():
  80. """
  81. :return: a list of parameterizable selector keywords
  82. """
  83. return ['ipaddress', 'macaddress']
  84. @staticmethod
  85. def _get_extractor_keywords():
  86. """
  87. :return: a list of extractor keywords
  88. """
  89. return ['random', 'first', 'last']
  90. def get_all_named_query_keywords(self):
  91. """
  92. :return: a list of all named query keywords, used to identify named queries
  93. """
  94. return (
  95. self._get_selector_keywords() + self._get_parametrized_selector_keywords() + self._get_extractor_keywords())
  96. @staticmethod
  97. def get_all_sql_query_keywords():
  98. """
  99. :return: a list of all supported SQL keywords, used to identify SQL queries
  100. """
  101. return ["select", "insert"]
  102. def process_user_defined_query(self, query_string: str, query_parameters: tuple = None):
  103. """
  104. Takes as input a SQL query query_string and optional a tuple of parameters which are marked by '?' in the query
  105. and later substituted.
  106. :param query_string: The query to execute
  107. :param query_parameters: The tuple of parameters to inject into the query
  108. :return: the results of the query
  109. """
  110. if query_parameters is not None:
  111. self.cursor.execute(query_string, query_parameters)
  112. else:
  113. self.cursor.execute(query_string)
  114. self.database.commit()
  115. return self.cursor.fetchall()
  116. def get_field_types(self, *table_names):
  117. """
  118. Creates a dictionary whose keys are the fields of the given table(s) and whose values are the appropriate field
  119. types, like TEXT for strings and REAL for float numbers.
  120. :param table_names: The name of table(s)
  121. :return: a dictionary of {field_name : field_type} for fields of all tables
  122. """
  123. dic = {}
  124. for table in table_names:
  125. self.cursor.execute("PRAGMA table_info('%s')" % table)
  126. results = self.cursor.fetchall()
  127. for field in results:
  128. dic[field[1].lower()] = field[2]
  129. return dic
  130. def named_query_parameterized(self, keyword: str, param_op_val: list):
  131. """
  132. Executes a parameterizable named query.
  133. :param keyword: The query to be executed, like ipaddress or macadress
  134. :param param_op_val: A list consisting of triples with (parameter, operator, value)
  135. :return: the results of the executed query
  136. """
  137. named_queries = {
  138. "ipaddress": "SELECT DISTINCT ip_statistics.ipAddress from ip_statistics INNER JOIN ip_mac, ip_ttl, "
  139. "ip_ports, ip_protocols ON ip_statistics.ipAddress=ip_mac.ipAddress AND "
  140. "ip_statistics.ipAddress=ip_ttl.ipAddress AND ip_statistics.ipAddress=ip_ports.ipAddress "
  141. "AND ip_statistics.ipAddress=ip_protocols.ipAddress WHERE ",
  142. "macaddress": "SELECT DISTINCT macAddress from ip_mac WHERE "}
  143. query = named_queries.get(keyword)
  144. field_types = self.get_field_types('ip_mac', 'ip_ttl', 'ip_ports', 'ip_protocols', 'ip_statistics', 'ip_mac')
  145. conditions = []
  146. for key, op, value in param_op_val:
  147. # Check whether the value is not a simple value, but another query (or list)
  148. if isinstance(value, pp.ParseResults):
  149. if value[0] == "list":
  150. # We have a list, cut the token off and use the remaining elements
  151. value = value[1:]
  152. # Lists can only be used with "in"
  153. if op is not "in":
  154. raise QueryExecutionException("List values require the usage of the 'in' operator!")
  155. else:
  156. # If we have another query instead of a direct value, execute and replace it
  157. rvalue = self._execute_query_list(value)
  158. # Do we have a comparison operator with a multiple-result query?
  159. if op is not "in" and value[0] in ['most_used', 'least_used', 'all', 'ipaddress_param',
  160. 'macaddress_param']:
  161. raise QueryExecutionException("The extractor '" + value[0] +
  162. "' may return more than one result!")
  163. # Make value contain a simple list with the results of the query
  164. value = map(lambda x: str(x[0]), rvalue)
  165. else:
  166. # Make sure value is a list now to simplify handling
  167. value = [value]
  168. # this makes sure that TEXT fields are queried by strings,
  169. # e.g. ipAddress=192.168.178.1 --is-converted-to--> ipAddress='192.168.178.1'
  170. if field_types.get(key) == 'TEXT':
  171. def ensure_string(x):
  172. if not str(x).startswith("'") and not str(x).startswith('"'):
  173. return "'" + x + "'"
  174. else:
  175. return x
  176. value = map(ensure_string, value)
  177. # If we have more than one value, join them together, separated by commas
  178. value = ",".join(map(str, value))
  179. # this replacement is required to remove ambiguity in SQL query
  180. if key == 'ipAddress':
  181. key = 'ip_mac.ipAddress'
  182. conditions.append(key + " " + op + " (" + str(value) + ")")
  183. where_clause = " AND ".join(conditions)
  184. query += where_clause
  185. self.cursor.execute(query)
  186. return self.cursor.fetchall()
  187. named_queries = {
  188. "most_used.ipaddress": "SELECT ipAddress FROM ip_statistics WHERE (pktsSent+pktsReceived) == "
  189. "(SELECT MAX(pktsSent+pktsReceived) from ip_statistics) ORDER BY ipAddress ASC",
  190. "most_used.macaddress": "SELECT macAddress FROM (SELECT macAddress, COUNT(*) as occ from ip_mac GROUP BY "
  191. "macAddress) WHERE occ=(SELECT COUNT(*) as occ from ip_mac GROUP BY macAddress "
  192. "ORDER BY occ DESC LIMIT 1) ORDER BY macAddress ASC",
  193. "most_used.portnumber": "SELECT portNumber FROM ip_ports GROUP BY portNumber HAVING COUNT(portNumber)="
  194. "(SELECT MAX(cntPort) from (SELECT portNumber, COUNT(portNumber) as cntPort FROM "
  195. "ip_ports GROUP BY portNumber)) ORDER BY portNumber ASC",
  196. "most_used.protocolname": "SELECT protocolName FROM ip_protocols GROUP BY protocolName HAVING "
  197. "COUNT(protocolCount)=(SELECT COUNT(protocolCount) as cnt FROM ip_protocols "
  198. "GROUP BY protocolName ORDER BY cnt DESC LIMIT 1) ORDER BY protocolName ASC",
  199. "most_used.ttlvalue": "SELECT ttlValue FROM (SELECT ttlValue, SUM(ttlCount) as occ FROM ip_ttl GROUP BY "
  200. "ttlValue) WHERE occ=(SELECT SUM(ttlCount) as occ FROM ip_ttl GROUP BY ttlValue "
  201. "ORDER BY occ DESC LIMIT 1) ORDER BY ttlValue ASC",
  202. "most_used.mssvalue": "SELECT mssValue FROM (SELECT mssValue, SUM(mssCount) as occ FROM tcp_mss GROUP BY "
  203. "mssValue) WHERE occ=(SELECT SUM(mssCount) as occ FROM tcp_mss GROUP BY mssValue "
  204. "ORDER BY occ DESC LIMIT 1) ORDER BY mssValue ASC",
  205. "most_used.winsize": "SELECT winSize FROM (SELECT winSize, SUM(winCount) as occ FROM tcp_win GROUP BY "
  206. "winSize) WHERE occ=(SELECT SUM(winCount) as occ FROM tcp_win GROUP BY winSize ORDER "
  207. "BY occ DESC LIMIT 1) ORDER BY winSize ASC",
  208. "most_used.ipclass": "SELECT ipClass FROM (SELECT ipClass, COUNT(*) as occ from ip_statistics GROUP BY "
  209. "ipClass ORDER BY occ DESC) WHERE occ=(SELECT COUNT(*) as occ from ip_statistics "
  210. "GROUP BY ipClass ORDER BY occ DESC LIMIT 1) ORDER BY ipClass ASC",
  211. "least_used.ipaddress": "SELECT ipAddress FROM ip_statistics WHERE (pktsSent+pktsReceived) == (SELECT "
  212. "MIN(pktsSent+pktsReceived) from ip_statistics) ORDER BY ipAddress ASC",
  213. "least_used.macaddress": "SELECT macAddress FROM (SELECT macAddress, COUNT(*) as occ from ip_mac GROUP "
  214. "BY macAddress) WHERE occ=(SELECT COUNT(*) as occ from ip_mac GROUP BY macAddress "
  215. "ORDER BY occ ASC LIMIT 1) ORDER BY macAddress ASC",
  216. "least_used.portnumber": "SELECT portNumber FROM ip_ports GROUP BY portNumber HAVING COUNT(portNumber)="
  217. "(SELECT MIN(cntPort) from (SELECT portNumber, COUNT(portNumber) as cntPort FROM "
  218. "ip_ports GROUP BY portNumber)) ORDER BY portNumber ASC",
  219. "least_used.protocolname": "SELECT protocolName FROM ip_protocols GROUP BY protocolName HAVING "
  220. "COUNT(protocolCount)=(SELECT COUNT(protocolCount) as cnt FROM ip_protocols "
  221. "GROUP BY protocolName ORDER BY cnt ASC LIMIT 1) ORDER BY protocolName ASC",
  222. "least_used.ttlvalue": "SELECT ttlValue FROM (SELECT ttlValue, SUM(ttlCount) as occ FROM ip_ttl GROUP BY "
  223. "ttlValue) WHERE occ=(SELECT SUM(ttlCount) as occ FROM ip_ttl GROUP BY ttlValue "
  224. "ORDER BY occ ASC LIMIT 1) ORDER BY ttlValue ASC",
  225. "least_used.mssvalue": "SELECT mssValue FROM (SELECT mssValue, SUM(mssCount) as occ FROM tcp_mss GROUP BY "
  226. "mssValue) WHERE occ=(SELECT SUM(mssCount) as occ FROM tcp_mss GROUP BY mssValue "
  227. "ORDER BY occ ASC LIMIT 1) ORDER BY mssValue ASC",
  228. "least_used.winsize": "SELECT winSize FROM (SELECT winSize, SUM(winCount) as occ FROM tcp_win GROUP BY "
  229. "winSize) WHERE occ=(SELECT SUM(winCount) as occ FROM tcp_win GROUP BY winSize "
  230. "ORDER BY occ ASC LIMIT 1) ORDER BY winSize ASC",
  231. "least_used.ipclass": "SELECT ipClass FROM (SELECT ipClass, COUNT(*) as occ from ip_statistics GROUP BY "
  232. "ipClass ORDER BY occ DESC) WHERE occ=(SELECT COUNT(*) as occ from ip_statistics "
  233. "GROUP BY ipClass ORDER BY occ ASC LIMIT 1) ORDER BY ipClass ASC",
  234. "avg.pktsreceived": "SELECT avg(pktsReceived) from ip_statistics",
  235. "avg.pktssent": "SELECT avg(pktsSent) from ip_statistics",
  236. "avg.kbytesreceived": "SELECT avg(kbytesReceived) from ip_statistics",
  237. "avg.kbytessent": "SELECT avg(kbytesSent) from ip_statistics",
  238. "avg.ttlvalue": "SELECT avg(ttlValue) from ip_ttl",
  239. "avg.mss": "SELECT avg(mssValue) from tcp_mss",
  240. "all.ipaddress": "SELECT ipAddress from ip_statistics ORDER BY ipAddress ASC",
  241. "all.ttlvalue": "SELECT DISTINCT ttlValue from ip_ttl ORDER BY ttlValue ASC",
  242. "all.mss": "SELECT DISTINCT mssValue from tcp_mss ORDER BY mssValue ASC",
  243. "all.macaddress": "SELECT DISTINCT macAddress from ip_mac ORDER BY macAddress ASC",
  244. "all.portnumber": "SELECT DISTINCT portNumber from ip_ports ORDER BY portNumber ASC",
  245. "all.protocolname": "SELECT DISTINCT protocolName from ip_protocols ORDER BY protocolName ASC",
  246. "all.winsize": "SELECT DISTINCT winSize FROM tcp_win ORDER BY winSize ASC",
  247. "all.ipclass": "SELECT DISTINCT ipClass FROM ip_statistics ORDER BY ipClass ASC"}
  248. def _execute_query_list(self, query_list):
  249. """
  250. Recursively executes a list of named queries. They are of the following form:
  251. ['macaddress_param', [['ipaddress', 'in', ['most_used', 'ipaddress']]]]
  252. :param query_list: The query statement list obtained from the query parser
  253. :return: The result of the query (either a single result or a list).
  254. """
  255. if query_list[0] == "random":
  256. return [rnd.choice(self._execute_query_list(query_list[1:]))]
  257. elif query_list[0] == "first":
  258. return [self._execute_query_list(query_list[1:])[0]]
  259. elif query_list[0] == "last":
  260. return [self._execute_query_list(query_list[1:])[-1]]
  261. elif query_list[0] == "macaddress_param":
  262. return self.named_query_parameterized("macaddress", query_list[1])
  263. elif query_list[0] == "ipaddress_param":
  264. return self.named_query_parameterized("ipaddress", query_list[1])
  265. else:
  266. query = self.named_queries.get(query_list[0] + "." + query_list[1])
  267. if query is None:
  268. raise QueryExecutionException("The requested query '" + query_list[0] + "(" + query_list[1] +
  269. ")' was not found in the internal query list!")
  270. self.cursor.execute(str(query))
  271. # TODO: fetch query on demand
  272. last_result = self.cursor.fetchall()
  273. return last_result
  274. def process_db_query(self, query_string_in: str, print_results=False, sql_query_parameters: tuple = None):
  275. """
  276. Processes a database query. This can either be a standard SQL query or a named query (predefined query).
  277. :param query_string_in: The string containing the query
  278. :param print_results: Indicated whether the results should be printed to terminal (True) or not (False)
  279. :param sql_query_parameters: Parameters for the SQL query (optional)
  280. :return: the results of the query
  281. """
  282. named_query_keywords = self.get_all_named_query_keywords()
  283. # Clean query_string
  284. query_string = query_string_in.lower().lstrip()
  285. # query_string is a user-defined SQL query
  286. result = None
  287. if sql_query_parameters is not None or query_string.startswith("select") or query_string.startswith("insert"):
  288. result = self.process_user_defined_query(query_string, sql_query_parameters)
  289. # query string is a named query -> parse it and pass it to statisticsDB
  290. elif any(k in query_string for k in named_query_keywords) and all(k in query_string for k in ['(', ')']):
  291. if query_string[-1] != ";":
  292. query_string += ";"
  293. query_list = self.query_parser.parse_query(query_string)
  294. result = self._execute_query_list(query_list)
  295. else:
  296. sys.stderr.write(
  297. "Query invalid. Only named queries and SQL SELECT/INSERT allowed. Please check the query's syntax!\n")
  298. return
  299. # If result is tuple/list with single element, extract value from list
  300. requires_extraction = (isinstance(result, list) or isinstance(result, tuple)) and len(result) == 1 and \
  301. (not isinstance(result[0], tuple) or len(result[0]) == 1)
  302. while requires_extraction:
  303. if isinstance(result, list) or isinstance(result, tuple):
  304. result = result[0]
  305. else:
  306. requires_extraction = False
  307. # If tuple of tuples or list of tuples, each consisting of single element is returned,
  308. # then convert it into list of values, because the returned column is clearly specified by the given query
  309. if (isinstance(result, tuple) or isinstance(result, list)) and all(len(val) == 1 for val in result):
  310. result = [c for c in result for c in c]
  311. # Print results if option print_results is True
  312. if print_results:
  313. if isinstance(result, list) and len(result) == 1:
  314. result = result[0]
  315. print("Query returned 1 record:\n")
  316. for i in range(0, len(result)):
  317. print(str(self.cursor.description[i][0]) + ": " + str(result[i]))
  318. else:
  319. self._print_query_results(query_string_in, result if isinstance(result, list) else [result])
  320. return result
  321. def process_interval_statistics_query(self, query_string_in: str):
  322. """
  323. :param query_string_in:
  324. :return:
  325. """
  326. table_name = self.process_db_query("SELECT name FROM interval_tables WHERE is_default=1")
  327. return self.process_user_defined_query(query_string_in % table_name)
  328. def _print_query_results(self, query_string_in: str, result: typing.List[typing.Union[str, float, int]]) -> None:
  329. """
  330. Prints the results of a query.
  331. Based on http://stackoverflow.com/a/20383011/3017719.
  332. :param query_string_in: The query the results belong to
  333. :param result: The list of query results
  334. """
  335. # Print number of results according to type of result
  336. if len(result) == 1:
  337. print("Query returned 1 record:\n")
  338. else:
  339. print("Query returned " + str(len(result)) + " records:\n")
  340. # Print query results
  341. if query_string_in.lstrip().upper().startswith(
  342. "SELECT") and result is not None and self.cursor.description is not None:
  343. widths = []
  344. columns = []
  345. tavnit = '|'
  346. separator = '+'
  347. for index, cd in enumerate(self.cursor.description):
  348. max_col_length = 0
  349. if len(result) > 0:
  350. max_col_length = max(list(map(lambda x:
  351. len(str(x[index] if len(self.cursor.description) > 1 else x)),
  352. result)))
  353. widths.append(max(len(cd[0]), max_col_length))
  354. columns.append(cd[0])
  355. for w in widths:
  356. tavnit += " %-" + "%ss |" % (w,)
  357. separator += '-' * w + '--+'
  358. print(separator)
  359. print(tavnit % tuple(columns))
  360. print(separator)
  361. for row in result:
  362. print(tavnit % row)
  363. print(separator)
  364. else:
  365. print(result)