queries.py 6.8 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204
  1. from collections import defaultdict
  2. import operator
  3. import db
  4. def search(q):
  5. like_str = '{}%'.format(q)
  6. with db.cursor() as c:
  7. alliances = db.query(c, '''
  8. SELECT DISTINCT alliance_id, alliance_name FROM characters
  9. WHERE alliance_name LIKE ? LIMIT 25
  10. ''', like_str)
  11. corps = db.query(c, '''
  12. SELECT DISTINCT corporation_id, corporation_name FROM characters
  13. WHERE corporation_name LIKE ? LIMIT 25
  14. ''', like_str)
  15. chars = db.query(c, '''
  16. SELECT DISTINCT character_id, character_name FROM characters
  17. WHERE character_name LIKE ? LIMIT 25
  18. ''', like_str)
  19. return {'alliances': alliances, 'corporations': corps, 'characters': chars}
  20. def kill_list(entity_type, entity_id):
  21. with db.cursor() as c:
  22. kills = db.query(c, '''
  23. SELECT DISTINCT(kills.kill_id), kill_time, cost,
  24. solarSystemName AS system_name, security, regionName AS region
  25. FROM kills
  26. JOIN characters ON characters.kill_id = kills.kill_id
  27. JOIN kill_costs ON kill_costs.kill_id = kills.kill_id
  28. JOIN eve.mapSolarSystems ON solar_system_id = solarSystemID
  29. JOIN eve.mapRegions ON mapSolarSystems.regionID = mapRegions.regionID
  30. WHERE {}_id = ? LIMIT 100
  31. '''.format(entity_type), entity_id)
  32. kill_ids = list(map(operator.itemgetter('kill_id'), kills))
  33. char_rows = db.query(c, '''
  34. SELECT
  35. kill_id, victim, final_blow,
  36. character_id, character_name, corporation_id, corporation_name, alliance_id, alliance_name, faction_id, faction_name,
  37. ship_type_id, typeName AS ship_name
  38. FROM characters
  39. JOIN eve.invTypes ON ship_type_id = typeID
  40. WHERE kill_id IN ({})
  41. '''.format(','.join(map(str, kill_ids))))
  42. characters = defaultdict(dict)
  43. entity_name = None
  44. for kill_id in kill_ids:
  45. characters[kill_id]['attackers'] = 1 # count final_blow now
  46. for char in char_rows:
  47. kill_id = char['kill_id']
  48. if char['victim']:
  49. characters[kill_id]['victim'] = char
  50. elif char['final_blow']:
  51. characters[kill_id]['final_blow'] = char
  52. else:
  53. characters[kill_id]['attackers'] += 1
  54. if entity_name is None and char[entity_type + '_id'] == entity_id:
  55. entity_name = char[entity_type + '_name']
  56. for kill in kills:
  57. kill['kill_time'] = _format_kill_time(kill['kill_time'])
  58. kill['security_status'] = _security_status(kill['system_name'], kill['security'])
  59. chars = characters[kill['kill_id']]
  60. kill['victim'] = chars['victim']
  61. kill['final_blow'] = chars['final_blow']
  62. kill['attackers'] = chars['attackers']
  63. return {'entity_name': entity_name, 'kills': kills}
  64. def kill(kill_id):
  65. with db.cursor() as c:
  66. kill = db.get(c, '''
  67. SELECT kill_time, cost, solarSystemName AS system_name, security FROM kills
  68. JOIN kill_costs ON kill_costs.kill_id = kills.kill_id
  69. JOIN eve.mapSolarSystems ON solar_system_id = solarSystemID
  70. WHERE kills.kill_id = ?
  71. ''', kill_id)
  72. kill['kill_time'] = _format_kill_time(kill['kill_time'])
  73. kill['security_status'] = _security_status(kill['system_name'], kill['security'])
  74. characters = db.query(c, '''
  75. SELECT character_id, character_name, damage, victim, final_blow,
  76. corporation_id, corporation_name, alliance_id, alliance_name, faction_id, faction_name,
  77. ship_type_id, weapon_type_id,
  78. ship.typeName AS ship_name, weapon.typeName AS weapon_name
  79. FROM characters
  80. JOIN eve.invTypes AS ship ON ship_type_id = ship.typeID
  81. LEFT JOIN eve.invTypes AS weapon ON weapon_type_id = weapon.typeID
  82. WHERE kill_id = ?
  83. ''', kill_id)
  84. attackers = []
  85. for char in characters:
  86. if char['victim']:
  87. victim = char
  88. elif char['final_blow']:
  89. final_blow = char
  90. else:
  91. attackers.append(char)
  92. try:
  93. ship_cost = db.get(c, 'SELECT cost FROM item_costs WHERE type_id = ?',
  94. victim['ship_type_id'])
  95. victim['ship_cost'] = ship_cost['cost']
  96. except db.NoRowsException:
  97. victim['ship_cost'] = 0
  98. item_rows = db.query(c, '''
  99. SELECT items.type_id, flag, dropped, destroyed, singleton,
  100. cost, typeName AS item_name, capacity
  101. FROM items
  102. JOIN item_costs ON item_costs.type_id = items.type_id
  103. JOIN eve.invTypes ON items.type_id = typeID
  104. WHERE kill_id = ? ORDER BY flag ASC
  105. ''', kill_id)
  106. items = defaultdict(list)
  107. for item in item_rows:
  108. flag = item['flag']
  109. if 125 <= flag <= 132:
  110. slot = 'subsystem'
  111. elif 27 <= flag <= 34:
  112. slot = 'high'
  113. elif 19 <= flag <= 26:
  114. slot = 'medium'
  115. elif 11 <= flag <= 18:
  116. slot = 'low'
  117. elif 92 <= flag <= 99:
  118. slot = 'rig'
  119. elif flag == 87:
  120. slot = 'drone bay'
  121. elif flag == 5:
  122. slot = 'cargo'
  123. elif 133 <= flag <= 143:
  124. slot = 'special hold'
  125. elif flag == 89:
  126. slot = 'implant'
  127. else:
  128. slot = '???'
  129. items[slot].append(item)
  130. slot_rows = db.query(c, '''
  131. SELECT attributeID, valueInt, valueFloat FROM eve.dgmTypeAttributes
  132. WHERE typeID = ? AND attributeID IN (12, 13, 14, 1137, 1367)
  133. AND (valueInt != 0 OR valueFloat != 0.0)
  134. ''', victim['ship_type_id'])
  135. slot_mapping = {12: 'low', 13: 'medium', 14: 'high', 1137: 'rig', 1367: 'subsystem'}
  136. slots = dict.fromkeys(slot_mapping.values(), 0)
  137. for attr in slot_rows:
  138. slot = slot_mapping[attr['attributeID']]
  139. slots[slot] = attr['valueInt'] or int(attr['valueFloat']) # wtf CCP
  140. if slots['subsystem']:
  141. sub_ids = map(lambda s: str(s['type_id']), items['subsystem'])
  142. modifier_rows = db.query(c, '''
  143. SELECT attributeID, valueFloat FROM eve.dgmTypeAttributes
  144. WHERE typeID IN ({}) AND attributeID in (1374, 1375, 1376) and valueFloat != 0.0
  145. '''.format(','.join(sub_ids)))
  146. slot_mapping = {1374: 'high', 1375: 'medium', 1376: 'low'} # that's right, it's backwards for subs!
  147. for modifier in modifier_rows:
  148. slot = slot_mapping[modifier['attributeID']]
  149. slots[slot] += int(modifier['valueFloat']) # strangely, an improvement
  150. return {
  151. 'kill': kill,
  152. 'victim': victim,
  153. 'final_blow': final_blow,
  154. 'attackers': attackers,
  155. 'items': items,
  156. 'slots': slots,
  157. }
  158. def top_cost():
  159. with db.cursor() as c:
  160. kills = db.query(c, '''
  161. SELECT kills.kill_id, cost,
  162. ship_type_id, typeName as ship_name,
  163. solarSystemName AS system_name, security
  164. FROM kills
  165. JOIN kill_costs ON kill_costs.kill_id = kills.kill_id
  166. JOIN characters ON characters.kill_id = kills.kill_id
  167. JOIN eve.invTypes ON typeID = ship_type_id
  168. JOIN eve.mapSolarSystems ON solar_system_id = solarSystemID
  169. WHERE victim = 1
  170. ORDER BY cost DESC
  171. LIMIT 25
  172. ''')
  173. for kill in kills:
  174. kill['security_status'] = _security_status(kill['system_name'], kill['security'])
  175. return kills
  176. def _format_kill_time(kill_time):
  177. return kill_time.strftime('%Y-%m-%d %H:%m')
  178. def _security_status(system_name, security):
  179. wspace = False
  180. if system_name[0] == 'J':
  181. try:
  182. int(system_name[1:])
  183. wspace = True
  184. except ValueError:
  185. pass
  186. if wspace:
  187. security_status = '?'
  188. elif security >= 0.5:
  189. security_status = 'high'
  190. elif security > 0.0:
  191. security_status = 'low'
  192. else:
  193. security_status = 'null'
  194. return security_status