Database.java 25 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586
  1. package com.gmail.nossr50.database;
  2. import java.sql.Connection;
  3. import java.sql.DriverManager;
  4. import java.sql.PreparedStatement;
  5. import java.sql.ResultSet;
  6. import java.sql.SQLException;
  7. import java.util.ArrayList;
  8. import java.util.HashMap;
  9. import java.util.Map;
  10. import java.util.Properties;
  11. import org.bukkit.Bukkit;
  12. import org.bukkit.entity.Player;
  13. import com.gmail.nossr50.mcMMO;
  14. import com.gmail.nossr50.config.Config;
  15. import com.gmail.nossr50.datatypes.DatabaseUpdate;
  16. import com.gmail.nossr50.datatypes.McMMOPlayer;
  17. import com.gmail.nossr50.runnables.SQLReconnect;
  18. import com.gmail.nossr50.skills.SkillType;
  19. import com.gmail.nossr50.spout.SpoutStuff;
  20. import com.gmail.nossr50.spout.huds.SpoutHud;
  21. import com.gmail.nossr50.util.Users;
  22. public class Database {
  23. private static Config configInstance = Config.getInstance();
  24. private static String connectionString;
  25. private static String tablePrefix = configInstance.getMySQLTablePrefix();
  26. private static Connection connection = null;
  27. private static mcMMO plugin = null;
  28. // Scale waiting time by this much per failed attempt
  29. private static final double SCALING_FACTOR = 40;
  30. // Minimum wait in nanoseconds (default 500ms)
  31. private static final long MIN_WAIT = 500L*1000000L;
  32. // Maximum time to wait between reconnects (default 5 minutes)
  33. private static final long MAX_WAIT = 5L * 60L * 1000L * 1000000L;
  34. // How long to wait when checking if connection is valid (default 3 seconds)
  35. private static final int VALID_TIMEOUT = 3;
  36. // When next to try connecting to Database in nanoseconds
  37. private static long nextReconnectTimestamp = 0L;
  38. // How many connection attemtps have failed
  39. private static int reconnectAttempt = 0;
  40. public Database(mcMMO instance) {
  41. plugin = instance;
  42. checkConnected(); //Connect to MySQL
  43. }
  44. /**
  45. * Attempt to connect to the mySQL database.
  46. */
  47. public static void connect() {
  48. connectionString = "jdbc:mysql://" + configInstance.getMySQLServerName() + ":" + configInstance.getMySQLServerPort() + "/" + configInstance.getMySQLDatabaseName();
  49. try {
  50. mcMMO.p.getLogger().info("Attempting connection to MySQL...");
  51. // Force driver to load if not yet loaded
  52. Class.forName("com.mysql.jdbc.Driver");
  53. Properties connectionProperties = new Properties();
  54. connectionProperties.put("user", configInstance.getMySQLUserName());
  55. connectionProperties.put("password", configInstance.getMySQLUserPassword());
  56. connectionProperties.put("autoReconnect", "false");
  57. connectionProperties.put("maxReconnects", "0");
  58. connection = DriverManager.getConnection(connectionString, connectionProperties);
  59. mcMMO.p.getLogger().info("Connection to MySQL was a success!");
  60. } catch (SQLException ex) {
  61. connection = null;
  62. if (reconnectAttempt == 0 || reconnectAttempt >= 11) mcMMO.p.getLogger().info("Connection to MySQL failed!");
  63. } catch (ClassNotFoundException ex) {
  64. connection = null;
  65. if (reconnectAttempt == 0 || reconnectAttempt >= 11) mcMMO.p.getLogger().info("MySQL database driver not found!");
  66. }
  67. }
  68. /**
  69. * Attempt to create the database structure.
  70. */
  71. public void createStructure() {
  72. write("CREATE TABLE IF NOT EXISTS `" + tablePrefix + "users` ("
  73. + "`id` int(10) unsigned NOT NULL AUTO_INCREMENT,"
  74. + "`user` varchar(40) NOT NULL,"
  75. + "`lastlogin` int(32) unsigned NOT NULL,"
  76. + "PRIMARY KEY (`id`),"
  77. + "UNIQUE KEY `user` (`user`)) ENGINE=MyISAM DEFAULT CHARSET=latin1 AUTO_INCREMENT=1;");
  78. write("CREATE TABLE IF NOT EXISTS `" + tablePrefix + "huds` ("
  79. + "`user_id` int(10) unsigned NOT NULL,"
  80. + "`hudtype` varchar(50) NOT NULL DEFAULT 'STANDARD',"
  81. + "PRIMARY KEY (`user_id`),"
  82. + "FOREIGN KEY (`user_id`) REFERENCES `" + tablePrefix + "users` (`id`) "
  83. + "ON DELETE CASCADE) ENGINE=MyISAM DEFAULT CHARSET=latin1;");
  84. write("CREATE TABLE IF NOT EXISTS `" + tablePrefix + "cooldowns` ("
  85. + "`user_id` int(10) unsigned NOT NULL,"
  86. + "`taming` int(32) unsigned NOT NULL DEFAULT '0',"
  87. + "`mining` int(32) unsigned NOT NULL DEFAULT '0',"
  88. + "`woodcutting` int(32) unsigned NOT NULL DEFAULT '0',"
  89. + "`repair` int(32) unsigned NOT NULL DEFAULT '0',"
  90. + "`unarmed` int(32) unsigned NOT NULL DEFAULT '0',"
  91. + "`herbalism` int(32) unsigned NOT NULL DEFAULT '0',"
  92. + "`excavation` int(32) unsigned NOT NULL DEFAULT '0',"
  93. + "`archery` int(32) unsigned NOT NULL DEFAULT '0',"
  94. + "`swords` int(32) unsigned NOT NULL DEFAULT '0',"
  95. + "`axes` int(32) unsigned NOT NULL DEFAULT '0',"
  96. + "`acrobatics` int(32) unsigned NOT NULL DEFAULT '0',"
  97. + "`blast_mining` int(32) unsigned NOT NULL DEFAULT '0',"
  98. + "PRIMARY KEY (`user_id`),"
  99. + "FOREIGN KEY (`user_id`) REFERENCES `" + tablePrefix + "users` (`id`) "
  100. + "ON DELETE CASCADE) ENGINE=MyISAM DEFAULT CHARSET=latin1;");
  101. write("CREATE TABLE IF NOT EXISTS `" + tablePrefix + "skills` ("
  102. + "`user_id` int(10) unsigned NOT NULL,"
  103. + "`taming` int(10) unsigned NOT NULL DEFAULT '0',"
  104. + "`mining` int(10) unsigned NOT NULL DEFAULT '0',"
  105. + "`woodcutting` int(10) unsigned NOT NULL DEFAULT '0',"
  106. + "`repair` int(10) unsigned NOT NULL DEFAULT '0',"
  107. + "`unarmed` int(10) unsigned NOT NULL DEFAULT '0',"
  108. + "`herbalism` int(10) unsigned NOT NULL DEFAULT '0',"
  109. + "`excavation` int(10) unsigned NOT NULL DEFAULT '0',"
  110. + "`archery` int(10) unsigned NOT NULL DEFAULT '0',"
  111. + "`swords` int(10) unsigned NOT NULL DEFAULT '0',"
  112. + "`axes` int(10) unsigned NOT NULL DEFAULT '0',"
  113. + "`acrobatics` int(10) unsigned NOT NULL DEFAULT '0',"
  114. + "PRIMARY KEY (`user_id`),"
  115. + "FOREIGN KEY (`user_id`) REFERENCES `" + tablePrefix + "users` (`id`) "
  116. + "ON DELETE CASCADE) ENGINE=MyISAM DEFAULT CHARSET=latin1;");
  117. write("CREATE TABLE IF NOT EXISTS `" + tablePrefix + "experience` ("
  118. + "`user_id` int(10) unsigned NOT NULL,"
  119. + "`taming` int(10) unsigned NOT NULL DEFAULT '0',"
  120. + "`mining` int(10) unsigned NOT NULL DEFAULT '0',"
  121. + "`woodcutting` int(10) unsigned NOT NULL DEFAULT '0',"
  122. + "`repair` int(10) unsigned NOT NULL DEFAULT '0',"
  123. + "`unarmed` int(10) unsigned NOT NULL DEFAULT '0',"
  124. + "`herbalism` int(10) unsigned NOT NULL DEFAULT '0',"
  125. + "`excavation` int(10) unsigned NOT NULL DEFAULT '0',"
  126. + "`archery` int(10) unsigned NOT NULL DEFAULT '0',"
  127. + "`swords` int(10) unsigned NOT NULL DEFAULT '0',"
  128. + "`axes` int(10) unsigned NOT NULL DEFAULT '0',"
  129. + "`acrobatics` int(10) unsigned NOT NULL DEFAULT '0',"
  130. + "PRIMARY KEY (`user_id`),"
  131. + "FOREIGN KEY (`user_id`) REFERENCES `" + tablePrefix + "users` (`id`) "
  132. + "ON DELETE CASCADE) ENGINE=MyISAM DEFAULT CHARSET=latin1;");
  133. checkDatabaseStructure(DatabaseUpdate.FISHING);
  134. checkDatabaseStructure(DatabaseUpdate.BLAST_MINING);
  135. checkDatabaseStructure(DatabaseUpdate.CASCADE_DELETE);
  136. checkDatabaseStructure(DatabaseUpdate.INDEX);
  137. }
  138. /**
  139. * Check database structure for missing values.
  140. *
  141. * @param update Type of data to check updates for
  142. */
  143. public void checkDatabaseStructure(DatabaseUpdate update) {
  144. String sql = null;
  145. ResultSet resultSet = null;
  146. HashMap<Integer, ArrayList<String>> rows = new HashMap<Integer, ArrayList<String>>();
  147. switch (update) {
  148. case BLAST_MINING:
  149. sql = "SELECT * FROM `" + tablePrefix + "cooldowns` ORDER BY `" + tablePrefix + "cooldowns`.`blast_mining` ASC LIMIT 0 , 30";
  150. break;
  151. case CASCADE_DELETE:
  152. write("ALTER TABLE `" + tablePrefix + "huds` ADD FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON DELETE CASCADE;");
  153. write("ALTER TABLE `" + tablePrefix + "experience` ADD FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON DELETE CASCADE;");
  154. write("ALTER TABLE `" + tablePrefix + "cooldowns` ADD FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON DELETE CASCADE;");
  155. write("ALTER TABLE `" + tablePrefix + "skills` ADD FOREIGN KEY (`user_id`) REFERENCES `users`(`id`) ON DELETE CASCADE;");
  156. case FISHING:
  157. sql = "SELECT * FROM `" + tablePrefix + "experience` ORDER BY `" + tablePrefix + "experience`.`fishing` ASC LIMIT 0 , 30";
  158. break;
  159. case INDEX:
  160. if(read("SHOW INDEX FROM " + tablePrefix + "skills").size() != 13) {
  161. plugin.getLogger().info("Indexing tables, this may take a while on larger databases");
  162. write("ALTER TABLE `" + tablePrefix + "skills` ADD INDEX `idx_taming` (`taming`) USING BTREE, "
  163. + "ADD INDEX `idx_mining` (`mining`) USING BTREE, "
  164. + "ADD INDEX `idx_woodcutting` (`woodcutting`) USING BTREE, "
  165. + "ADD INDEX `idx_repair` (`repair`) USING BTREE, "
  166. + "ADD INDEX `idx_unarmed` (`unarmed`) USING BTREE, "
  167. + "ADD INDEX `idx_herbalism` (`herbalism`) USING BTREE, "
  168. + "ADD INDEX `idx_excavation` (`excavation`) USING BTREE, "
  169. + "ADD INDEX `idx_archery` (`archery`) USING BTREE, "
  170. + "ADD INDEX `idx_swords` (`swords`) USING BTREE, "
  171. + "ADD INDEX `idx_axes` (`axes`) USING BTREE, "
  172. + "ADD INDEX `idx_acrobatics` (`acrobatics`) USING BTREE, "
  173. + "ADD INDEX `idx_fishing` (`fishing`) USING BTREE;");
  174. }
  175. break;
  176. default:
  177. break;
  178. }
  179. PreparedStatement statement = null;
  180. try {
  181. if (!checkConnected()) return;
  182. statement = connection.prepareStatement(sql);
  183. resultSet = statement.executeQuery();
  184. while (resultSet.next()) {
  185. ArrayList<String> column = new ArrayList<String>();
  186. for (int i = 1; i <= resultSet.getMetaData().getColumnCount(); i++) {
  187. column.add(resultSet.getString(i));
  188. }
  189. rows.put(resultSet.getRow(), column);
  190. }
  191. }
  192. catch (SQLException ex) {
  193. switch (update) {
  194. case BLAST_MINING:
  195. mcMMO.p.getLogger().info("Updating mcMMO MySQL tables for Blast Mining...");
  196. write("ALTER TABLE `"+tablePrefix + "cooldowns` ADD `blast_mining` int(32) NOT NULL DEFAULT '0' ;");
  197. break;
  198. case FISHING:
  199. mcMMO.p.getLogger().info("Updating mcMMO MySQL tables for Fishing...");
  200. write("ALTER TABLE `"+tablePrefix + "skills` ADD `fishing` int(10) NOT NULL DEFAULT '0' ;");
  201. write("ALTER TABLE `"+tablePrefix + "experience` ADD `fishing` int(10) NOT NULL DEFAULT '0' ;");
  202. break;
  203. default:
  204. break;
  205. }
  206. } finally {
  207. if (resultSet != null) {
  208. try {
  209. resultSet.close();
  210. } catch (SQLException e) {
  211. // Ignore the error, we're leaving
  212. }
  213. }
  214. if (statement != null) {
  215. try {
  216. statement.close();
  217. } catch (SQLException e) {
  218. // Ignore the error, we're leaving
  219. }
  220. }
  221. }
  222. }
  223. /**
  224. * Attempt to write the SQL query.
  225. *
  226. * @param sql Query to write.
  227. * @return true if the query was successfully written, false otherwise.
  228. */
  229. public boolean write(String sql) {
  230. if (checkConnected()) {
  231. PreparedStatement statement = null;
  232. try {
  233. statement = connection.prepareStatement(sql);
  234. statement.executeUpdate();
  235. return true;
  236. }
  237. catch (SQLException ex) {
  238. printErrors(ex);
  239. return false;
  240. } finally {
  241. if (statement != null) {
  242. try {
  243. statement.close();
  244. } catch (SQLException e) {
  245. printErrors(e);
  246. return false;
  247. }
  248. }
  249. }
  250. }
  251. return false;
  252. }
  253. /**
  254. * Returns the number of rows affected by either a DELETE or UPDATE query
  255. *
  256. * @param sql SQL query to execute
  257. * @return the number of rows affected
  258. */
  259. public int update(String sql) {
  260. int ret = 0;
  261. if (checkConnected()) {
  262. PreparedStatement statement = null;
  263. try {
  264. statement = connection.prepareStatement(sql);
  265. ret = statement.executeUpdate();
  266. return ret;
  267. } catch (SQLException ex) {
  268. printErrors(ex);
  269. return 0;
  270. } finally {
  271. if (statement != null) {
  272. try {
  273. statement.close();
  274. } catch (SQLException e) {
  275. printErrors(e);
  276. return 0;
  277. }
  278. }
  279. }
  280. }
  281. return ret;
  282. }
  283. /**
  284. * Get the Integer. Only return first row / first field.
  285. *
  286. * @param sql SQL query to execute
  287. * @return the value in the first row / first field
  288. */
  289. public int getInt(String sql) {
  290. ResultSet resultSet;
  291. int result = 0;
  292. if (checkConnected()) {
  293. try {
  294. PreparedStatement statement = connection.prepareStatement(sql);
  295. resultSet = statement.executeQuery();
  296. if (resultSet.next()) {
  297. result = resultSet.getInt(1);
  298. }
  299. else {
  300. result = 0;
  301. }
  302. statement.close();
  303. }
  304. catch (SQLException ex) {
  305. printErrors(ex);
  306. }
  307. }
  308. return result;
  309. }
  310. /**
  311. * Check connection status and re-establish if dead or stale.
  312. *
  313. * If the very first immediate attempt fails, further attempts
  314. * will be made in progressively larger intervals up to MAX_WAIT
  315. * intervals.
  316. *
  317. * This allows for MySQL to time out idle connections as needed by
  318. * server operator, without affecting McMMO, while still providing
  319. * protection against a database outage taking down Bukkit's tick
  320. * processing loop due to attemping a database connection each
  321. * time McMMO needs the database.
  322. *
  323. * @return the boolean value for whether or not we are connected
  324. */
  325. public static boolean checkConnected() {
  326. boolean isClosed = true;
  327. boolean isValid = false;
  328. boolean exists = (connection != null);
  329. // If we're waiting for server to recover then leave early
  330. if (nextReconnectTimestamp > 0 && nextReconnectTimestamp > System.nanoTime()) {
  331. return false;
  332. }
  333. if (exists) {
  334. try {
  335. isClosed = connection.isClosed();
  336. } catch (SQLException e) {
  337. isClosed = true;
  338. e.printStackTrace();
  339. printErrors(e);
  340. }
  341. if (!isClosed) {
  342. try {
  343. isValid = connection.isValid(VALID_TIMEOUT);
  344. } catch (SQLException e) {
  345. // Don't print stack trace because it's valid to lose idle connections
  346. // to the server and have to restart them.
  347. isValid = false;
  348. }
  349. }
  350. }
  351. // Leave if all ok
  352. if (exists && !isClosed && isValid) {
  353. // Housekeeping
  354. nextReconnectTimestamp = 0;
  355. reconnectAttempt = 0;
  356. return true;
  357. }
  358. // Cleanup after ourselves for GC and MySQL's sake
  359. if (exists && !isClosed) {
  360. try {
  361. connection.close();
  362. } catch (SQLException ex) {
  363. // This is a housekeeping exercise, ignore errors
  364. }
  365. }
  366. // Try to connect again
  367. connect();
  368. // Leave if connection is good
  369. try {
  370. if (connection != null && !connection.isClosed()) {
  371. // Schedule a database save if we really had an outage
  372. if (reconnectAttempt > 1) {
  373. plugin.getServer().getScheduler().scheduleSyncDelayedTask(plugin, new SQLReconnect(plugin), 5);
  374. }
  375. nextReconnectTimestamp = 0;
  376. reconnectAttempt = 0;
  377. return true;
  378. }
  379. } catch (SQLException e) {
  380. // Failed to check isClosed, so presume connection is bad and attempt later
  381. e.printStackTrace();
  382. printErrors(e);
  383. }
  384. reconnectAttempt++;
  385. nextReconnectTimestamp = (long)(System.nanoTime() + Math.min(MAX_WAIT, (reconnectAttempt*SCALING_FACTOR*MIN_WAIT)));
  386. return false;
  387. }
  388. /**
  389. * Read SQL query.
  390. *
  391. * @param sql SQL query to read
  392. * @return the rows in this SQL query
  393. */
  394. public HashMap<Integer, ArrayList<String>> read(String sql) {
  395. ResultSet resultSet;
  396. HashMap<Integer, ArrayList<String>> rows = new HashMap<Integer, ArrayList<String>>();
  397. if (checkConnected()) {
  398. try {
  399. PreparedStatement statement = connection.prepareStatement(sql);
  400. resultSet = statement.executeQuery();
  401. while (resultSet.next()) {
  402. ArrayList<String> column = new ArrayList<String>();
  403. for (int i = 1; i <= resultSet.getMetaData().getColumnCount(); i++) {
  404. column.add(resultSet.getString(i));
  405. }
  406. rows.put(resultSet.getRow(), column);
  407. }
  408. statement.close();
  409. }
  410. catch (SQLException ex) {
  411. printErrors(ex);
  412. }
  413. }
  414. return rows;
  415. }
  416. public Map<String, Integer> readSQLRank(String playerName) {
  417. ResultSet resultSet;
  418. Map<String, Integer> skills = new HashMap<String, Integer>();
  419. if (checkConnected()) {
  420. try {
  421. for (SkillType skillType: SkillType.values()) {
  422. if (skillType.isChildSkill()) continue;
  423. String sql;
  424. if(skillType != SkillType.ALL) {
  425. sql = "SELECT COUNT(*) AS rank FROM " + tablePrefix + "users JOIN " + tablePrefix + "skills ON user_id = id WHERE " + skillType.name().toLowerCase() + " > 0 AND " + skillType.name().toLowerCase() + " > (SELECT " + skillType.name().toLowerCase() + " FROM " + tablePrefix + "users JOIN " + tablePrefix + "skills ON user_id = id WHERE user = '" + playerName + "')";
  426. } else {
  427. sql = "SELECT COUNT(*) AS rank FROM " + tablePrefix + "users JOIN " + tablePrefix + "skills ON user_id = id WHERE taming+mining+woodcutting+repair+unarmed+herbalism+excavation+archery+swords+axes+acrobatics+fishing > 0 AND taming+mining+woodcutting+repair+unarmed+herbalism+excavation+archery+swords+axes+acrobatics+fishing > (SELECT taming+mining+woodcutting+repair+unarmed+herbalism+excavation+archery+swords+axes+acrobatics+fishing FROM " + tablePrefix + "users JOIN " + tablePrefix + "skills ON user_id = id WHERE user = '" + playerName + "')";
  428. }
  429. PreparedStatement statement = connection.prepareStatement(sql);
  430. resultSet = statement.executeQuery();
  431. resultSet.next();
  432. int rank = resultSet.getInt("rank");
  433. if(skillType != SkillType.ALL) {
  434. sql = "SELECT user, " + skillType.name().toLowerCase() + " FROM " + tablePrefix + "users JOIN " + tablePrefix + "skills ON user_id = id WHERE " + skillType.name().toLowerCase() + " > 0 AND " + skillType.name().toLowerCase() + " = (SELECT " + skillType.name().toLowerCase() + " FROM " + tablePrefix + "users JOIN " + tablePrefix + "skills ON user_id = id WHERE user = '" + playerName + "') ORDER BY user";
  435. } else {
  436. sql = "SELECT user, taming+mining+woodcutting+repair+unarmed+herbalism+excavation+archery+swords+axes+acrobatics+fishing FROM " + tablePrefix + "users JOIN " + tablePrefix + "skills ON user_id = id WHERE taming+mining+woodcutting+repair+unarmed+herbalism+excavation+archery+swords+axes+acrobatics+fishing > 0 AND taming+mining+woodcutting+repair+unarmed+herbalism+excavation+archery+swords+axes+acrobatics+fishing = (SELECT taming+mining+woodcutting+repair+unarmed+herbalism+excavation+archery+swords+axes+acrobatics+fishing FROM " + tablePrefix + "users JOIN " + tablePrefix + "skills ON user_id = id WHERE user = '" + playerName + "') ORDER BY user";
  437. }
  438. statement = connection.prepareStatement(sql);
  439. resultSet = statement.executeQuery();
  440. while (resultSet.next()) {
  441. if(resultSet.getString("user").equalsIgnoreCase(playerName)) {
  442. skills.put(skillType.name(), rank + resultSet.getRow());
  443. break;
  444. }
  445. }
  446. statement.close();
  447. }
  448. }
  449. catch (SQLException ex) {
  450. printErrors(ex);
  451. }
  452. }
  453. return skills;
  454. }
  455. public void purgePowerlessSQL() {
  456. plugin.getLogger().info("Purging powerless users...");
  457. HashMap<Integer, ArrayList<String>> usernames = read("SELECT u.user FROM " + tablePrefix + "skills AS s, " + tablePrefix + "users AS u WHERE s.user_id = u.id AND (s.taming+s.mining+s.woodcutting+s.repair+s.unarmed+s.herbalism+s.excavation+s.archery+s.swords+s.axes+s.acrobatics+s.fishing) = 0");
  458. write("DELETE FROM " + tablePrefix + "users WHERE " + tablePrefix + "users.id IN (SELECT * FROM (SELECT u.id FROM " + tablePrefix + "skills AS s, " + tablePrefix + "users AS u WHERE s.user_id = u.id AND (s.taming+s.mining+s.woodcutting+s.repair+s.unarmed+s.herbalism+s.excavation+s.archery+s.swords+s.axes+s.acrobatics+s.fishing) = 0) AS p)");
  459. int purgedUsers = 0;
  460. for (int i = 1; i <= usernames.size(); i++) {
  461. String playerName = usernames.get(i).get(0);
  462. if (playerName == null || Bukkit.getOfflinePlayer(playerName).isOnline()) {
  463. continue;
  464. }
  465. profileCleanup(playerName);
  466. purgedUsers++;
  467. }
  468. plugin.getLogger().info("Purged " + purgedUsers + " users from the database.");
  469. }
  470. public void purgeOldSQL() {
  471. plugin.getLogger().info("Purging old users...");
  472. long currentTime = System.currentTimeMillis();
  473. long purgeTime = 2630000000L * Config.getInstance().getOldUsersCutoff();
  474. HashMap<Integer, ArrayList<String>> usernames = read("SELECT user FROM " + tablePrefix + "users WHERE ((" + currentTime + " - lastlogin*1000) > " + purgeTime + ")");
  475. write("DELETE FROM " + tablePrefix + "users WHERE " + tablePrefix + "users.id IN (SELECT * FROM (SELECT id FROM " + tablePrefix + "users WHERE ((" + currentTime + " - lastlogin*1000) > " + purgeTime + ")) AS p)");
  476. int purgedUsers = 0;
  477. for (int i = 1; i <= usernames.size(); i++) {
  478. String playerName = usernames.get(i).get(0);
  479. if (playerName == null) {
  480. continue;
  481. }
  482. profileCleanup(playerName);
  483. purgedUsers++;
  484. }
  485. plugin.getLogger().info("Purged " + purgedUsers + " users from the database.");
  486. }
  487. private static void printErrors(SQLException ex) {
  488. System.out.println("SQLException: " + ex.getMessage());
  489. System.out.println("SQLState: " + ex.getSQLState());
  490. System.out.println("VendorError: " + ex.getErrorCode());
  491. }
  492. public static void profileCleanup(String playerName) {
  493. McMMOPlayer mcmmoPlayer = Users.getPlayer(playerName);
  494. if (mcmmoPlayer != null) {
  495. Player player = mcmmoPlayer.getPlayer();
  496. SpoutHud spoutHud = mcmmoPlayer.getProfile().getSpoutHud();
  497. if (spoutHud != null) {
  498. spoutHud.removeWidgets();
  499. }
  500. Users.remove(playerName);
  501. if (player.isOnline()) {
  502. Users.addUser(player);
  503. if (mcMMO.spoutEnabled) {
  504. SpoutStuff.reloadSpoutPlayer(player);
  505. }
  506. }
  507. }
  508. }
  509. }